Fix SQL Server 2008 compatibility (#3916)

* Fixed a bug in the performance counter query when run against SQL Server 2016 SP1-CU2. The performance counter DMV contains duplicate entries which are not handled by the query.

* Adding more stats related to workload groups.

* Adding new RG stats, removing "host" tag

* Removed workload group query

* Fixing some 2008 compat issues, removed the host field from the result set.

* Adding fixes for SQL Server 2008 compat around RG columns. Also converted perf counter query to support named instances.
This commit is contained in:
Mark Wilkinson - m82labs 2018-03-22 13:38:40 -04:00 committed by Daniel Nelson
parent ed6e5b40c3
commit cce1601a54
2 changed files with 227 additions and 194 deletions

View File

@ -52,8 +52,7 @@ GO
## - DatabaseStats ## - DatabaseStats
## - MemoryClerk ## - MemoryClerk
## - VolumeSpace ## - VolumeSpace
## - PerformanceMetrics exclude_query = [ 'DatabaseIO' ]
# exclude_query = [ 'PerformanceCounters','WaitStatsCatagorized' ]
``` ```
### Metrics: ### Metrics:
@ -130,5 +129,5 @@ The following metrics can be used directly, with no delta calculations:
- SQLServer:Workload Group Stats\Requests completed/sec - SQLServer:Workload Group Stats\Requests completed/sec
Version 2 queries have the following tags: Version 2 queries have the following tags:
- `host`: Physical host name
- `sql_instance`: Physical host and instance name (hostname:instance) - `sql_instance`: Physical host and instance name (hostname:instance)

View File

@ -68,7 +68,7 @@ var sampleConfig = `
## - MemoryClerk ## - MemoryClerk
## - VolumeSpace ## - VolumeSpace
## - PerformanceMetrics ## - PerformanceMetrics
# exclude_query = [ 'PerformanceCounters','WaitStatsCatagorized' ] # exclude_query = [ 'DatabaseIO' ]
` `
// SampleConfig return the sample configuration // SampleConfig return the sample configuration
@ -244,102 +244,108 @@ func init() {
// Thanks Bob Ward (http://aka.ms/bobwardms) // Thanks Bob Ward (http://aka.ms/bobwardms)
// and the folks at Stack Overflow (https://github.com/opserver/Opserver/blob/9c89c7e9936b58ad237b30e6f4cc6cd59c406889/Opserver.Core/Data/SQL/SQLInstance.Memory.cs) // and the folks at Stack Overflow (https://github.com/opserver/Opserver/blob/9c89c7e9936b58ad237b30e6f4cc6cd59c406889/Opserver.Core/Data/SQL/SQLInstance.Memory.cs)
// for putting most of the memory clerk definitions online! // for putting most of the memory clerk definitions online!
const sqlMemoryClerkV2 = `SELECT const sqlMemoryClerkV2 = `DECLARE @SQL NVARCHAR(MAX) = 'SELECT
'sqlserver_memory_clerks' As [measurement], "sqlserver_memory_clerks" As [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], REPLACE(@@SERVERNAME,"\",":") AS [sql_instance],
SERVERPROPERTY('ServerName') AS [host],
ISNULL(clerk_names.name,mc.type) AS clerk_type, ISNULL(clerk_names.name,mc.type) AS clerk_type,
SUM(mc.pages_kb) AS size_kb SUM({pages_kb}) AS size_kb
FROM FROM
sys.dm_os_memory_clerks AS mc WITH (NOLOCK) sys.dm_os_memory_clerks AS mc WITH (NOLOCK)
LEFT OUTER JOIN ( VALUES LEFT OUTER JOIN ( VALUES
('CACHESTORE_BROKERDSH','Service Broker Dialog Security Header Cache'), ("CACHESTORE_BROKERDSH","Service Broker Dialog Security Header Cache"),
('CACHESTORE_BROKERKEK','Service Broker Key Exchange Key Cache'), ("CACHESTORE_BROKERKEK","Service Broker Key Exchange Key Cache"),
('CACHESTORE_BROKERREADONLY','Service Broker (Read-Only)'), ("CACHESTORE_BROKERREADONLY","Service Broker (Read-Only)"),
('CACHESTORE_BROKERRSB','Service Broker Null Remote Service Binding Cache'), ("CACHESTORE_BROKERRSB","Service Broker Null Remote Service Binding Cache"),
('CACHESTORE_BROKERTBLACS','Broker dormant rowsets'), ("CACHESTORE_BROKERTBLACS","Broker dormant rowsets"),
('CACHESTORE_BROKERTO','Service Broker Transmission Object Cache'), ("CACHESTORE_BROKERTO","Service Broker Transmission Object Cache"),
('CACHESTORE_BROKERUSERCERTLOOKUP','Service Broker user certificates lookup result cache'), ("CACHESTORE_BROKERUSERCERTLOOKUP","Service Broker user certificates lookup result cache"),
('CACHESTORE_CLRPROC','CLR Procedure Cache'), ("CACHESTORE_CLRPROC","CLR Procedure Cache"),
('CACHESTORE_CLRUDTINFO','CLR UDT Info'), ("CACHESTORE_CLRUDTINFO","CLR UDT Info"),
('CACHESTORE_COLUMNSTOREOBJECTPOOL','Column Store Object Pool'), ("CACHESTORE_COLUMNSTOREOBJECTPOOL","Column Store Object Pool"),
('CACHESTORE_CONVPRI','Conversation Priority Cache'), ("CACHESTORE_CONVPRI","Conversation Priority Cache"),
('CACHESTORE_EVENTS','Event Notification Cache'), ("CACHESTORE_EVENTS","Event Notification Cache"),
('CACHESTORE_FULLTEXTSTOPLIST','Full Text Stoplist Cache'), ("CACHESTORE_FULLTEXTSTOPLIST","Full Text Stoplist Cache"),
('CACHESTORE_NOTIF','Notification Store'), ("CACHESTORE_NOTIF","Notification Store"),
('CACHESTORE_OBJCP','Object Plans'), ("CACHESTORE_OBJCP","Object Plans"),
('CACHESTORE_PHDR','Bound Trees'), ("CACHESTORE_PHDR","Bound Trees"),
('CACHESTORE_SEARCHPROPERTYLIST','Search Property List Cache'), ("CACHESTORE_SEARCHPROPERTYLIST","Search Property List Cache"),
('CACHESTORE_SEHOBTCOLUMNATTRIBUTE','SE Shared Column Metadata Cache'), ("CACHESTORE_SEHOBTCOLUMNATTRIBUTE","SE Shared Column Metadata Cache"),
('CACHESTORE_SQLCP','SQL Plans'), ("CACHESTORE_SQLCP","SQL Plans"),
('CACHESTORE_STACKFRAMES','SOS_StackFramesStore'), ("CACHESTORE_STACKFRAMES","SOS_StackFramesStore"),
('CACHESTORE_SYSTEMROWSET','System Rowset Store'), ("CACHESTORE_SYSTEMROWSET","System Rowset Store"),
('CACHESTORE_TEMPTABLES','Temporary Tables & Table Variables'), ("CACHESTORE_TEMPTABLES","Temporary Tables & Table Variables"),
('CACHESTORE_VIEWDEFINITIONS','View Definition Cache'), ("CACHESTORE_VIEWDEFINITIONS","View Definition Cache"),
('CACHESTORE_XML_SELECTIVE_DG','XML DB Cache (Selective)'), ("CACHESTORE_XML_SELECTIVE_DG","XML DB Cache (Selective)"),
('CACHESTORE_XMLDBATTRIBUTE','XML DB Cache (Attribute)'), ("CACHESTORE_XMLDBATTRIBUTE","XML DB Cache (Attribute)"),
('CACHESTORE_XMLDBELEMENT','XML DB Cache (Element)'), ("CACHESTORE_XMLDBELEMENT","XML DB Cache (Element)"),
('CACHESTORE_XMLDBTYPE','XML DB Cache (Type)'), ("CACHESTORE_XMLDBTYPE","XML DB Cache (Type)"),
('CACHESTORE_XPROC','Extended Stored Procedures'), ("CACHESTORE_XPROC","Extended Stored Procedures"),
('MEMORYCLERK_FILETABLE','Memory Clerk (File Table)'), ("MEMORYCLERK_FILETABLE","Memory Clerk (File Table)"),
('MEMORYCLERK_FSCHUNKER','Memory Clerk (FS Chunker)'), ("MEMORYCLERK_FSCHUNKER","Memory Clerk (FS Chunker)"),
('MEMORYCLERK_FULLTEXT','Full Text'), ("MEMORYCLERK_FULLTEXT","Full Text"),
('MEMORYCLERK_FULLTEXT_SHMEM','Full-text IG'), ("MEMORYCLERK_FULLTEXT_SHMEM","Full-text IG"),
('MEMORYCLERK_HADR','HADR'), ("MEMORYCLERK_HADR","HADR"),
('MEMORYCLERK_HOST','Host'), ("MEMORYCLERK_HOST","Host"),
('MEMORYCLERK_LANGSVC','Language Service'), ("MEMORYCLERK_LANGSVC","Language Service"),
('MEMORYCLERK_LWC','Light Weight Cache'), ("MEMORYCLERK_LWC","Light Weight Cache"),
('MEMORYCLERK_QSRANGEPREFETCH','QS Range Prefetch'), ("MEMORYCLERK_QSRANGEPREFETCH","QS Range Prefetch"),
('MEMORYCLERK_SERIALIZATION','Serialization'), ("MEMORYCLERK_SERIALIZATION","Serialization"),
('MEMORYCLERK_SNI','SNI'), ("MEMORYCLERK_SNI","SNI"),
('MEMORYCLERK_SOSMEMMANAGER','SOS Memory Manager'), ("MEMORYCLERK_SOSMEMMANAGER","SOS Memory Manager"),
('MEMORYCLERK_SOSNODE','SOS Node'), ("MEMORYCLERK_SOSNODE","SOS Node"),
('MEMORYCLERK_SOSOS','SOS Memory Clerk'), ("MEMORYCLERK_SOSOS","SOS Memory Clerk"),
('MEMORYCLERK_SQLBUFFERPOOL','Buffer Pool'), ("MEMORYCLERK_SQLBUFFERPOOL","Buffer Pool"),
('MEMORYCLERK_SQLCLR','CLR'), ("MEMORYCLERK_SQLCLR","CLR"),
('MEMORYCLERK_SQLCLRASSEMBLY','CLR Assembly'), ("MEMORYCLERK_SQLCLRASSEMBLY","CLR Assembly"),
('MEMORYCLERK_SQLCONNECTIONPOOL','Connection Pool'), ("MEMORYCLERK_SQLCONNECTIONPOOL","Connection Pool"),
('MEMORYCLERK_SQLGENERAL','General'), ("MEMORYCLERK_SQLGENERAL","General"),
('MEMORYCLERK_SQLHTTP','HTTP'), ("MEMORYCLERK_SQLHTTP","HTTP"),
('MEMORYCLERK_SQLLOGPOOL','Log Pool'), ("MEMORYCLERK_SQLLOGPOOL","Log Pool"),
('MEMORYCLERK_SQLOPTIMIZER','SQL Optimizer'), ("MEMORYCLERK_SQLOPTIMIZER","SQL Optimizer"),
('MEMORYCLERK_SQLQERESERVATIONS','SQL Reservations'), ("MEMORYCLERK_SQLQERESERVATIONS","SQL Reservations"),
('MEMORYCLERK_SQLQUERYCOMPILE','SQL Query Compile'), ("MEMORYCLERK_SQLQUERYCOMPILE","SQL Query Compile"),
('MEMORYCLERK_SQLQUERYEXEC','SQL Query Exec'), ("MEMORYCLERK_SQLQUERYEXEC","SQL Query Exec"),
('MEMORYCLERK_SQLQUERYPLAN','SQL Query Plan'), ("MEMORYCLERK_SQLQUERYPLAN","SQL Query Plan"),
('MEMORYCLERK_SQLSERVICEBROKER','SQL Service Broker'), ("MEMORYCLERK_SQLSERVICEBROKER","SQL Service Broker"),
('MEMORYCLERK_SQLSERVICEBROKERTRANSPORT','Unified Communication Stack'), ("MEMORYCLERK_SQLSERVICEBROKERTRANSPORT","Unified Communication Stack"),
('MEMORYCLERK_SQLSOAP','SQL SOAP'), ("MEMORYCLERK_SQLSOAP","SQL SOAP"),
('MEMORYCLERK_SQLSOAPSESSIONSTORE','SQL SOAP (Session Store)'), ("MEMORYCLERK_SQLSOAPSESSIONSTORE","SQL SOAP (Session Store)"),
('MEMORYCLERK_SQLSTORENG','SQL Storage Engine'), ("MEMORYCLERK_SQLSTORENG","SQL Storage Engine"),
('MEMORYCLERK_SQLUTILITIES','SQL Utilities'), ("MEMORYCLERK_SQLUTILITIES","SQL Utilities"),
('MEMORYCLERK_SQLXML','SQL XML'), ("MEMORYCLERK_SQLXML","SQL XML"),
('MEMORYCLERK_SQLXP','SQL XP'), ("MEMORYCLERK_SQLXP","SQL XP"),
('MEMORYCLERK_TRACE_EVTNOTIF','Trace Event Notification'), ("MEMORYCLERK_TRACE_EVTNOTIF","Trace Event Notification"),
('MEMORYCLERK_XE','XE Engine'), ("MEMORYCLERK_XE","XE Engine"),
('MEMORYCLERK_XE_BUFFER','XE Buffer'), ("MEMORYCLERK_XE_BUFFER","XE Buffer"),
('MEMORYCLERK_XTP','In-Memory OLTP'), ("MEMORYCLERK_XTP","In-Memory OLTP"),
('OBJECTSTORE_LBSS','Lbss Cache (Object Store)'), ("OBJECTSTORE_LBSS","Lbss Cache (Object Store)"),
('OBJECTSTORE_LOCK_MANAGER','Lock Manager (Object Store)'), ("OBJECTSTORE_LOCK_MANAGER","Lock Manager (Object Store)"),
('OBJECTSTORE_SECAUDIT_EVENT_BUFFER','Audit Event Buffer (Object Store)'), ("OBJECTSTORE_SECAUDIT_EVENT_BUFFER","Audit Event Buffer (Object Store)"),
('OBJECTSTORE_SERVICE_BROKER','Service Broker (Object Store)'), ("OBJECTSTORE_SERVICE_BROKER","Service Broker (Object Store)"),
('OBJECTSTORE_SNI_PACKET','SNI Packet (Object Store)'), ("OBJECTSTORE_SNI_PACKET","SNI Packet (Object Store)"),
('OBJECTSTORE_XACT_CACHE','Transactions Cache (Object Store)'), ("OBJECTSTORE_XACT_CACHE","Transactions Cache (Object Store)"),
('USERSTORE_DBMETADATA','DB Metadata (User Store)'), ("USERSTORE_DBMETADATA","DB Metadata (User Store)"),
('USERSTORE_OBJPERM','Object Permissions (User Store)'), ("USERSTORE_OBJPERM","Object Permissions (User Store)"),
('USERSTORE_SCHEMAMGR','Schema Manager (User Store)'), ("USERSTORE_SCHEMAMGR","Schema Manager (User Store)"),
('USERSTORE_SXC','SXC (User Store)'), ("USERSTORE_SXC","SXC (User Store)"),
('USERSTORE_TOKENPERM','Token Permissions (User Store)'), ("USERSTORE_TOKENPERM","Token Permissions (User Store)"),
('USERSTORE_QDSSTMT','QDS Statement Buffer (Pre-persist)'), ("USERSTORE_QDSSTMT","QDS Statement Buffer (Pre-persist)"),
('CACHESTORE_QDSRUNTIMESTATS','QDS Runtime Stats (Pre-persist)'), ("CACHESTORE_QDSRUNTIMESTATS","QDS Runtime Stats (Pre-persist)"),
('CACHESTORE_QDSCONTEXTSETTINGS','QDS Unique Context Settings'), ("CACHESTORE_QDSCONTEXTSETTINGS","QDS Unique Context Settings"),
('MEMORYCLERK_QUERYDISKSTORE','QDS General'), ("MEMORYCLERK_QUERYDISKSTORE","QDS General"),
('MEMORYCLERK_QUERYDISKSTORE_HASHMAP','QDS Query/Plan Hash Table') ("MEMORYCLERK_QUERYDISKSTORE_HASHMAP","QDS Query/Plan Hash Table")
) AS clerk_names(system_name,name) ) AS clerk_names(system_name,name)
ON mc.type = clerk_names.system_name ON mc.type = clerk_names.system_name
GROUP BY ISNULL(clerk_names.name,mc.type) GROUP BY ISNULL(clerk_names.name,mc.type)
HAVING SUM(pages_kb) >= 1024 HAVING SUM({pages_kb}) >= 1024
OPTION( RECOMPILE ); OPTION( RECOMPILE );'
IF CAST(LEFT(CAST(SERVERPROPERTY('productversion') as varchar), 2) AS INT) > 10 -- SQL Server 2008 Compat
SET @SQL = REPLACE(REPLACE(@SQL,'{pages_kb}','mc.pages_kb'),'"','''')
ELSE
SET @SQL = REPLACE(REPLACE(@SQL,'{pages_kb}','mc.single_pages_kb + mc.multi_pages_kb'),'"','''')
EXEC(@SQL)
` `
const sqlDatabaseIOV2 = `SELECT const sqlDatabaseIOV2 = `SELECT
@ -368,13 +374,12 @@ const sqlServerPropertiesV2 = `DECLARE @sys_info TABLE (
IF OBJECT_ID('master.sys.dm_os_sys_info') IS NOT NULL IF OBJECT_ID('master.sys.dm_os_sys_info') IS NOT NULL
BEGIN BEGIN
INSERT INTO @sys_info ( cpu_count, server_memory, uptime ) INSERT INTO @sys_info ( cpu_count, server_memory, uptime )
EXEC('SELECT cpu_count, physical_memory_kb, DATEDIFF(MINUTE,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info') EXEC('SELECT cpu_count, (select total_physical_memory_kb from sys.dm_os_sys_memory) AS physical_memory_kb, DATEDIFF(MINUTE,sqlserver_start_time,GETDATE()) FROM sys.dm_os_sys_info')
END END
SELECT SELECT
'sqlserver_server_properties' As [measurement], 'sqlserver_server_properties' As [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
SERVERPROPERTY('ServerName') AS [host],
SUM( CASE WHEN state = 0 THEN 1 ELSE 0 END ) AS db_online, SUM( CASE WHEN state = 0 THEN 1 ELSE 0 END ) AS db_online,
SUM( CASE WHEN state = 1 THEN 1 ELSE 0 END ) AS db_restoring, SUM( CASE WHEN state = 1 THEN 1 ELSE 0 END ) AS db_restoring,
SUM( CASE WHEN state = 2 THEN 1 ELSE 0 END ) AS db_recovering, SUM( CASE WHEN state = 2 THEN 1 ELSE 0 END ) AS db_recovering,
@ -393,7 +398,10 @@ CROSS APPLY (
OPTION( RECOMPILE ); OPTION( RECOMPILE );
` `
const sqlPerformanceCountersV2 string = `DECLARE @PCounters TABLE const sqlPerformanceCountersV2 string = `DECLARE @DynamicPerf NVARCHAR(MAX) = ''
SET @DynamicPerf += REPLACE('
DECLARE @PCounters TABLE
( (
object_name nvarchar(128), object_name nvarchar(128),
counter_name nvarchar(128), counter_name nvarchar(128),
@ -413,130 +421,157 @@ SELECT DISTINCT
FROM sys.dm_os_performance_counters AS spi FROM sys.dm_os_performance_counters AS spi
WHERE ( WHERE (
counter_name IN ( counter_name IN (
'SQL Compilations/sec', "SQL Compilations/sec",
'SQL Re-Compilations/sec', "SQL Re-Compilations/sec",
'User Connections', "User Connections",
'Batch Requests/sec', "Batch Requests/sec",
'Logouts/sec', "Logouts/sec",
'Logins/sec', "Logins/sec",
'Processes blocked', "Processes blocked",
'Latch Waits/sec', "Latch Waits/sec",
'Full Scans/sec', "Full Scans/sec",
'Index Searches/sec', "Index Searches/sec",
'Page Splits/sec', "Page Splits/sec",
'Page Lookups/sec', "Page Lookups/sec",
'Page Reads/sec', "Page Reads/sec",
'Page Writes/sec', "Page Writes/sec",
'Readahead Pages/sec', "Readahead Pages/sec",
'Lazy Writes/sec', "Lazy Writes/sec",
'Checkpoint Pages/sec', "Checkpoint Pages/sec",
'Page life expectancy', "Page life expectancy",
'Log File(s) Size (KB)', "Log File(s) Size (KB)",
'Log File(s) Used Size (KB)', "Log File(s) Used Size (KB)",
'Data File(s) Size (KB)', "Data File(s) Size (KB)",
'Transactions/sec', "Transactions/sec",
'Write Transactions/sec', "Write Transactions/sec",
'Active Temp Tables', "Active Temp Tables",
'Temp Tables Creation Rate', "Temp Tables Creation Rate",
'Temp Tables For Destruction', "Temp Tables For Destruction",
'Free Space in tempdb (KB)', "Free Space in tempdb (KB)",
'Version Store Size (KB)', "Version Store Size (KB)",
'Memory Grants Pending', "Memory Grants Pending",
'Free list stalls/sec', "Free list stalls/sec",
'Buffer cache hit ratio', "Buffer cache hit ratio",
'Buffer cache hit ratio base', "Buffer cache hit ratio base",
'Backup/Restore Throughput/sec', "Backup/Restore Throughput/sec",
'Total Server Memory (KB)', "Total Server Memory (KB)",
'Target Server Memory (KB)' "Target Server Memory (KB)"
) )
) OR ( ) OR (
instance_name IN ('_Total','Column store object pool') instance_name IN ("_Total","Column store object pool")
AND counter_name IN ( AND counter_name IN (
'Log Flushes/sec', "Log Flushes/sec",
'Log Flush Wait Time', "Log Flush Wait Time",
'Lock Timeouts/sec', "Lock Timeouts/sec",
'Number of Deadlocks/sec', "Number of Deadlocks/sec",
'Lock Waits/sec', "Lock Waits/sec",
'Latch Waits/sec', "Latch Waits/sec",
'Memory broker clerk size', "Memory broker clerk size",
'Log Bytes Flushed/sec', "Log Bytes Flushed/sec",
'Bytes Sent to Replica/sec', "Bytes Sent to Replica/sec",
'Log Send Queue', "Log Send Queue",
'Bytes Sent to Transport/sec', "Bytes Sent to Transport/sec",
'Sends to Replica/sec', "Sends to Replica/sec",
'Bytes Sent to Transport/sec', "Bytes Sent to Transport/sec",
'Sends to Transport/sec', "Sends to Transport/sec",
'Bytes Received from Replica/sec', "Bytes Received from Replica/sec",
'Receives from Replica/sec', "Receives from Replica/sec",
'Flow Control Time (ms/sec)', "Flow Control Time (ms/sec)",
'Flow Control/sec', "Flow Control/sec",
'Resent Messages/sec', "Resent Messages/sec",
'Redone Bytes/sec', "Redone Bytes/sec",
'XTP Memory Used (KB)' "XTP Memory Used (KB)"
) OR ( ) OR (
object_name = 'SQLServer:Database Replica' counter_name IN (
AND counter_name IN ( "Log Bytes Received/sec",
'Log Bytes Received/sec', "Log Apply Pending Queue",
'Log Apply Pending Queue', "Redone Bytes/sec",
'Redone Bytes/sec', "Recovery Queue",
'Recovery Queue', "Log Apply Ready Queue"
'Log Apply Ready Queue'
) )
AND instance_name = '_Total' AND instance_name = "_Total"
) )
) OR ( ) OR (
object_name = 'SQLServer:Database Replica' counter_name IN ("Transaction Delay")
AND counter_name IN ('Transaction Delay')
) OR ( ) OR (
object_name = 'SQLServer:Workload Group Stats' counter_name IN (
AND counter_name IN ( "CPU usage %",
'CPU usage %', "CPU usage % base",
'CPU usage % base', "Queued requests",
'Queued requests', "Requests completed/sec",
'Requests completed/sec', "Blocked tasks"
'Blocked tasks'
) )
) OR ( ) OR (
object_name = 'SQLServer:Resource Pool Stats' counter_name IN (
AND counter_name IN ( "Active memory grant amount (KB)",
'Active memory grant amount (KB)', "Disk Read Bytes/sec",
'Disk Read Bytes/sec', "Disk Read IO Throttled/sec",
'Disk Read IO Throttled/sec', "Disk Read IO/sec",
'Disk Read IO/sec', "Disk Write Bytes/sec",
'Disk Write Bytes/sec', "Disk Write IO Throttled/sec",
'Disk Write IO Throttled/sec', "Disk Write IO/sec",
'Disk Write IO/sec', "Used memory (KB)"
'Used memory (KB)'
) )
) OR object_name IN ( ) OR (
'SQLServer:User Settable', object_name LIKE "%User Settable%"
'SQLServer:SQL Errors' OR object_name LIKE "%SQL Errors%"
) )
'
,'"','''')
SELECT 'sqlserver_performance' AS [measurement], SET @DynamicPerf += REPLACE('
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], SELECT "sqlserver_performance" AS [measurement],
SERVERPROPERTY('ServerName') AS [host], REPLACE(@@SERVERNAME,"\",":") AS [sql_instance],
pc.object_name AS [object], pc.object_name AS [object],
pc.counter_name AS [counter], pc.counter_name AS [counter],
CASE pc.instance_name WHEN '_Total' THEN 'Total' ELSE ISNULL(pc.instance_name,'') END AS [instance], CASE pc.instance_name WHEN "_Total" THEN "Total" ELSE ISNULL(pc.instance_name,"") END AS [instance],
CASE WHEN pc.cntr_type = 537003264 AND pc1.cntr_value > 0 THEN (pc.cntr_value * 1.0) / (pc1.cntr_value * 1.0) * 100 ELSE pc.cntr_value END AS [value] CASE WHEN pc.cntr_type = 537003264 AND pc1.cntr_value > 0 THEN (pc.cntr_value * 1.0) / (pc1.cntr_value * 1.0) * 100 ELSE pc.cntr_value END AS [value]
FROM @PCounters AS pc FROM @PCounters AS pc
LEFT OUTER JOIN @PCounters AS pc1 LEFT OUTER JOIN @PCounters AS pc1
ON ( ON (
pc.counter_name = REPLACE(pc1.counter_name,' base','') pc.counter_name = REPLACE(pc1.counter_name," base","")
OR pc.counter_name = REPLACE(pc1.counter_name,' base',' (ms)') OR pc.counter_name = REPLACE(pc1.counter_name," base"," (ms)")
) )
AND pc.object_name = pc1.object_name AND pc.object_name = pc1.object_name
AND pc.instance_name = pc1.instance_name AND pc.instance_name = pc1.instance_name
AND pc1.counter_name LIKE '%base' AND pc1.counter_name LIKE "%base"
WHERE pc.counter_name NOT LIKE '% base' WHERE pc.counter_name NOT LIKE "% base"
OPTION( RECOMPILE ); UNION ALL
SELECT
"sqlserver_performance" As [measurement],
REPLACE(@@SERVERNAME,"\",":") AS [sql_instance],
"SQLServer:Workload Group Stats" AS object,
counter,
instance,
vs.value
FROM
(
SELECT
rgwg.name AS instance,
rgwg.total_request_count AS "Request Count",
rgwg.total_queued_request_count AS "Queued Request Count",
rgwg.total_cpu_limit_violation_count AS "CPU Limit Violation Count",
rgwg.total_cpu_usage_ms AS "CPU Usage (time)",
' + CASE WHEN SERVERPROPERTY('ProductMajorVersion') > 10 THEN 'rgwg.total_cpu_usage_preemptive_ms AS "Premptive CPU Usage (time)",' ELSE '' END + '
rgwg.total_lock_wait_count AS "Lock Wait Count",
rgwg.total_lock_wait_time_ms AS "Lock Wait Time",
rgwg.total_reduced_memgrant_count AS "Reduced Memory Grant Count"
FROM sys.dm_resource_governor_workload_groups AS rgwg
INNER JOIN sys.dm_resource_governor_resource_pools AS rgrp
ON rgwg.pool_id = rgrp.pool_id
) AS rg
UNPIVOT (
value FOR counter IN ( [Request Count], [Queued Request Count], [CPU Limit Violation Count], [CPU Usage (time)], ' + CASE WHEN SERVERPROPERTY('ProductMajorVersion') > 10 THEN '[Premptive CPU Usage (time)], ' ELSE '' END + '[Lock Wait Count], [Lock Wait Time], [Reduced Memory Grant Count] )
) AS vs
OPTION(RECOMPILE);'
,'"','''')
EXEC(@DynamicPerf)
` `
const sqlWaitStatsCategorizedV2 string = `SELECT const sqlWaitStatsCategorizedV2 string = `SELECT
'sqlserver_waitstats' AS [measurement], 'sqlserver_waitstats' AS [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
SERVERPROPERTY('ServerName') AS [host],
ws.wait_type, ws.wait_type,
wait_time_ms, wait_time_ms,
wait_time_ms - signal_wait_time_ms AS [resource_wait_ms], wait_time_ms - signal_wait_time_ms AS [resource_wait_ms],
@ -1098,7 +1133,6 @@ BEGIN
SELECT TOP(1) SELECT TOP(1)
'sqlserver_azurestats' AS [measurement], 'sqlserver_azurestats' AS [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
SERVERPROPERTY('ServerName') AS [host],
avg_cpu_percent, avg_cpu_percent,
avg_data_io_percent, avg_data_io_percent,
avg_log_write_percent, avg_log_write_percent,