From cce1601a5406719270e16a630325a42e755e8a31 Mon Sep 17 00:00:00 2001 From: Mark Wilkinson - m82labs Date: Thu, 22 Mar 2018 13:38:40 -0400 Subject: [PATCH] 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. --- plugins/inputs/sqlserver/README.md | 5 +- plugins/inputs/sqlserver/sqlserver.go | 416 ++++++++++++++------------ 2 files changed, 227 insertions(+), 194 deletions(-) diff --git a/plugins/inputs/sqlserver/README.md b/plugins/inputs/sqlserver/README.md index 6a5b62d6d..766bb95e0 100644 --- a/plugins/inputs/sqlserver/README.md +++ b/plugins/inputs/sqlserver/README.md @@ -52,8 +52,7 @@ GO ## - DatabaseStats ## - MemoryClerk ## - VolumeSpace - ## - PerformanceMetrics - # exclude_query = [ 'PerformanceCounters','WaitStatsCatagorized' ] + exclude_query = [ 'DatabaseIO' ] ``` ### Metrics: @@ -130,5 +129,5 @@ The following metrics can be used directly, with no delta calculations: - SQLServer:Workload Group Stats\Requests completed/sec Version 2 queries have the following tags: -- `host`: Physical host name - `sql_instance`: Physical host and instance name (hostname:instance) + diff --git a/plugins/inputs/sqlserver/sqlserver.go b/plugins/inputs/sqlserver/sqlserver.go index 7d945f791..f17574a9e 100644 --- a/plugins/inputs/sqlserver/sqlserver.go +++ b/plugins/inputs/sqlserver/sqlserver.go @@ -68,7 +68,7 @@ var sampleConfig = ` ## - MemoryClerk ## - VolumeSpace ## - PerformanceMetrics - # exclude_query = [ 'PerformanceCounters','WaitStatsCatagorized' ] + # exclude_query = [ 'DatabaseIO' ] ` // SampleConfig return the sample configuration @@ -244,102 +244,108 @@ func init() { // 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) // for putting most of the memory clerk definitions online! -const sqlMemoryClerkV2 = `SELECT -'sqlserver_memory_clerks' As [measurement], -REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], -SERVERPROPERTY('ServerName') AS [host], +const sqlMemoryClerkV2 = `DECLARE @SQL NVARCHAR(MAX) = 'SELECT +"sqlserver_memory_clerks" As [measurement], +REPLACE(@@SERVERNAME,"\",":") AS [sql_instance], ISNULL(clerk_names.name,mc.type) AS clerk_type, -SUM(mc.pages_kb) AS size_kb +SUM({pages_kb}) AS size_kb FROM sys.dm_os_memory_clerks AS mc WITH (NOLOCK) LEFT OUTER JOIN ( VALUES -('CACHESTORE_BROKERDSH','Service Broker Dialog Security Header Cache'), -('CACHESTORE_BROKERKEK','Service Broker Key Exchange Key Cache'), -('CACHESTORE_BROKERREADONLY','Service Broker (Read-Only)'), -('CACHESTORE_BROKERRSB','Service Broker Null Remote Service Binding Cache'), -('CACHESTORE_BROKERTBLACS','Broker dormant rowsets'), -('CACHESTORE_BROKERTO','Service Broker Transmission Object Cache'), -('CACHESTORE_BROKERUSERCERTLOOKUP','Service Broker user certificates lookup result cache'), -('CACHESTORE_CLRPROC','CLR Procedure Cache'), -('CACHESTORE_CLRUDTINFO','CLR UDT Info'), -('CACHESTORE_COLUMNSTOREOBJECTPOOL','Column Store Object Pool'), -('CACHESTORE_CONVPRI','Conversation Priority Cache'), -('CACHESTORE_EVENTS','Event Notification Cache'), -('CACHESTORE_FULLTEXTSTOPLIST','Full Text Stoplist Cache'), -('CACHESTORE_NOTIF','Notification Store'), -('CACHESTORE_OBJCP','Object Plans'), -('CACHESTORE_PHDR','Bound Trees'), -('CACHESTORE_SEARCHPROPERTYLIST','Search Property List Cache'), -('CACHESTORE_SEHOBTCOLUMNATTRIBUTE','SE Shared Column Metadata Cache'), -('CACHESTORE_SQLCP','SQL Plans'), -('CACHESTORE_STACKFRAMES','SOS_StackFramesStore'), -('CACHESTORE_SYSTEMROWSET','System Rowset Store'), -('CACHESTORE_TEMPTABLES','Temporary Tables & Table Variables'), -('CACHESTORE_VIEWDEFINITIONS','View Definition Cache'), -('CACHESTORE_XML_SELECTIVE_DG','XML DB Cache (Selective)'), -('CACHESTORE_XMLDBATTRIBUTE','XML DB Cache (Attribute)'), -('CACHESTORE_XMLDBELEMENT','XML DB Cache (Element)'), -('CACHESTORE_XMLDBTYPE','XML DB Cache (Type)'), -('CACHESTORE_XPROC','Extended Stored Procedures'), -('MEMORYCLERK_FILETABLE','Memory Clerk (File Table)'), -('MEMORYCLERK_FSCHUNKER','Memory Clerk (FS Chunker)'), -('MEMORYCLERK_FULLTEXT','Full Text'), -('MEMORYCLERK_FULLTEXT_SHMEM','Full-text IG'), -('MEMORYCLERK_HADR','HADR'), -('MEMORYCLERK_HOST','Host'), -('MEMORYCLERK_LANGSVC','Language Service'), -('MEMORYCLERK_LWC','Light Weight Cache'), -('MEMORYCLERK_QSRANGEPREFETCH','QS Range Prefetch'), -('MEMORYCLERK_SERIALIZATION','Serialization'), -('MEMORYCLERK_SNI','SNI'), -('MEMORYCLERK_SOSMEMMANAGER','SOS Memory Manager'), -('MEMORYCLERK_SOSNODE','SOS Node'), -('MEMORYCLERK_SOSOS','SOS Memory Clerk'), -('MEMORYCLERK_SQLBUFFERPOOL','Buffer Pool'), -('MEMORYCLERK_SQLCLR','CLR'), -('MEMORYCLERK_SQLCLRASSEMBLY','CLR Assembly'), -('MEMORYCLERK_SQLCONNECTIONPOOL','Connection Pool'), -('MEMORYCLERK_SQLGENERAL','General'), -('MEMORYCLERK_SQLHTTP','HTTP'), -('MEMORYCLERK_SQLLOGPOOL','Log Pool'), -('MEMORYCLERK_SQLOPTIMIZER','SQL Optimizer'), -('MEMORYCLERK_SQLQERESERVATIONS','SQL Reservations'), -('MEMORYCLERK_SQLQUERYCOMPILE','SQL Query Compile'), -('MEMORYCLERK_SQLQUERYEXEC','SQL Query Exec'), -('MEMORYCLERK_SQLQUERYPLAN','SQL Query Plan'), -('MEMORYCLERK_SQLSERVICEBROKER','SQL Service Broker'), -('MEMORYCLERK_SQLSERVICEBROKERTRANSPORT','Unified Communication Stack'), -('MEMORYCLERK_SQLSOAP','SQL SOAP'), -('MEMORYCLERK_SQLSOAPSESSIONSTORE','SQL SOAP (Session Store)'), -('MEMORYCLERK_SQLSTORENG','SQL Storage Engine'), -('MEMORYCLERK_SQLUTILITIES','SQL Utilities'), -('MEMORYCLERK_SQLXML','SQL XML'), -('MEMORYCLERK_SQLXP','SQL XP'), -('MEMORYCLERK_TRACE_EVTNOTIF','Trace Event Notification'), -('MEMORYCLERK_XE','XE Engine'), -('MEMORYCLERK_XE_BUFFER','XE Buffer'), -('MEMORYCLERK_XTP','In-Memory OLTP'), -('OBJECTSTORE_LBSS','Lbss Cache (Object Store)'), -('OBJECTSTORE_LOCK_MANAGER','Lock Manager (Object Store)'), -('OBJECTSTORE_SECAUDIT_EVENT_BUFFER','Audit Event Buffer (Object Store)'), -('OBJECTSTORE_SERVICE_BROKER','Service Broker (Object Store)'), -('OBJECTSTORE_SNI_PACKET','SNI Packet (Object Store)'), -('OBJECTSTORE_XACT_CACHE','Transactions Cache (Object Store)'), -('USERSTORE_DBMETADATA','DB Metadata (User Store)'), -('USERSTORE_OBJPERM','Object Permissions (User Store)'), -('USERSTORE_SCHEMAMGR','Schema Manager (User Store)'), -('USERSTORE_SXC','SXC (User Store)'), -('USERSTORE_TOKENPERM','Token Permissions (User Store)'), -('USERSTORE_QDSSTMT','QDS Statement Buffer (Pre-persist)'), -('CACHESTORE_QDSRUNTIMESTATS','QDS Runtime Stats (Pre-persist)'), -('CACHESTORE_QDSCONTEXTSETTINGS','QDS Unique Context Settings'), -('MEMORYCLERK_QUERYDISKSTORE','QDS General'), -('MEMORYCLERK_QUERYDISKSTORE_HASHMAP','QDS Query/Plan Hash Table') +("CACHESTORE_BROKERDSH","Service Broker Dialog Security Header Cache"), +("CACHESTORE_BROKERKEK","Service Broker Key Exchange Key Cache"), +("CACHESTORE_BROKERREADONLY","Service Broker (Read-Only)"), +("CACHESTORE_BROKERRSB","Service Broker Null Remote Service Binding Cache"), +("CACHESTORE_BROKERTBLACS","Broker dormant rowsets"), +("CACHESTORE_BROKERTO","Service Broker Transmission Object Cache"), +("CACHESTORE_BROKERUSERCERTLOOKUP","Service Broker user certificates lookup result cache"), +("CACHESTORE_CLRPROC","CLR Procedure Cache"), +("CACHESTORE_CLRUDTINFO","CLR UDT Info"), +("CACHESTORE_COLUMNSTOREOBJECTPOOL","Column Store Object Pool"), +("CACHESTORE_CONVPRI","Conversation Priority Cache"), +("CACHESTORE_EVENTS","Event Notification Cache"), +("CACHESTORE_FULLTEXTSTOPLIST","Full Text Stoplist Cache"), +("CACHESTORE_NOTIF","Notification Store"), +("CACHESTORE_OBJCP","Object Plans"), +("CACHESTORE_PHDR","Bound Trees"), +("CACHESTORE_SEARCHPROPERTYLIST","Search Property List Cache"), +("CACHESTORE_SEHOBTCOLUMNATTRIBUTE","SE Shared Column Metadata Cache"), +("CACHESTORE_SQLCP","SQL Plans"), +("CACHESTORE_STACKFRAMES","SOS_StackFramesStore"), +("CACHESTORE_SYSTEMROWSET","System Rowset Store"), +("CACHESTORE_TEMPTABLES","Temporary Tables & Table Variables"), +("CACHESTORE_VIEWDEFINITIONS","View Definition Cache"), +("CACHESTORE_XML_SELECTIVE_DG","XML DB Cache (Selective)"), +("CACHESTORE_XMLDBATTRIBUTE","XML DB Cache (Attribute)"), +("CACHESTORE_XMLDBELEMENT","XML DB Cache (Element)"), +("CACHESTORE_XMLDBTYPE","XML DB Cache (Type)"), +("CACHESTORE_XPROC","Extended Stored Procedures"), +("MEMORYCLERK_FILETABLE","Memory Clerk (File Table)"), +("MEMORYCLERK_FSCHUNKER","Memory Clerk (FS Chunker)"), +("MEMORYCLERK_FULLTEXT","Full Text"), +("MEMORYCLERK_FULLTEXT_SHMEM","Full-text IG"), +("MEMORYCLERK_HADR","HADR"), +("MEMORYCLERK_HOST","Host"), +("MEMORYCLERK_LANGSVC","Language Service"), +("MEMORYCLERK_LWC","Light Weight Cache"), +("MEMORYCLERK_QSRANGEPREFETCH","QS Range Prefetch"), +("MEMORYCLERK_SERIALIZATION","Serialization"), +("MEMORYCLERK_SNI","SNI"), +("MEMORYCLERK_SOSMEMMANAGER","SOS Memory Manager"), +("MEMORYCLERK_SOSNODE","SOS Node"), +("MEMORYCLERK_SOSOS","SOS Memory Clerk"), +("MEMORYCLERK_SQLBUFFERPOOL","Buffer Pool"), +("MEMORYCLERK_SQLCLR","CLR"), +("MEMORYCLERK_SQLCLRASSEMBLY","CLR Assembly"), +("MEMORYCLERK_SQLCONNECTIONPOOL","Connection Pool"), +("MEMORYCLERK_SQLGENERAL","General"), +("MEMORYCLERK_SQLHTTP","HTTP"), +("MEMORYCLERK_SQLLOGPOOL","Log Pool"), +("MEMORYCLERK_SQLOPTIMIZER","SQL Optimizer"), +("MEMORYCLERK_SQLQERESERVATIONS","SQL Reservations"), +("MEMORYCLERK_SQLQUERYCOMPILE","SQL Query Compile"), +("MEMORYCLERK_SQLQUERYEXEC","SQL Query Exec"), +("MEMORYCLERK_SQLQUERYPLAN","SQL Query Plan"), +("MEMORYCLERK_SQLSERVICEBROKER","SQL Service Broker"), +("MEMORYCLERK_SQLSERVICEBROKERTRANSPORT","Unified Communication Stack"), +("MEMORYCLERK_SQLSOAP","SQL SOAP"), +("MEMORYCLERK_SQLSOAPSESSIONSTORE","SQL SOAP (Session Store)"), +("MEMORYCLERK_SQLSTORENG","SQL Storage Engine"), +("MEMORYCLERK_SQLUTILITIES","SQL Utilities"), +("MEMORYCLERK_SQLXML","SQL XML"), +("MEMORYCLERK_SQLXP","SQL XP"), +("MEMORYCLERK_TRACE_EVTNOTIF","Trace Event Notification"), +("MEMORYCLERK_XE","XE Engine"), +("MEMORYCLERK_XE_BUFFER","XE Buffer"), +("MEMORYCLERK_XTP","In-Memory OLTP"), +("OBJECTSTORE_LBSS","Lbss Cache (Object Store)"), +("OBJECTSTORE_LOCK_MANAGER","Lock Manager (Object Store)"), +("OBJECTSTORE_SECAUDIT_EVENT_BUFFER","Audit Event Buffer (Object Store)"), +("OBJECTSTORE_SERVICE_BROKER","Service Broker (Object Store)"), +("OBJECTSTORE_SNI_PACKET","SNI Packet (Object Store)"), +("OBJECTSTORE_XACT_CACHE","Transactions Cache (Object Store)"), +("USERSTORE_DBMETADATA","DB Metadata (User Store)"), +("USERSTORE_OBJPERM","Object Permissions (User Store)"), +("USERSTORE_SCHEMAMGR","Schema Manager (User Store)"), +("USERSTORE_SXC","SXC (User Store)"), +("USERSTORE_TOKENPERM","Token Permissions (User Store)"), +("USERSTORE_QDSSTMT","QDS Statement Buffer (Pre-persist)"), +("CACHESTORE_QDSRUNTIMESTATS","QDS Runtime Stats (Pre-persist)"), +("CACHESTORE_QDSCONTEXTSETTINGS","QDS Unique Context Settings"), +("MEMORYCLERK_QUERYDISKSTORE","QDS General"), +("MEMORYCLERK_QUERYDISKSTORE_HASHMAP","QDS Query/Plan Hash Table") ) AS clerk_names(system_name,name) ON mc.type = clerk_names.system_name GROUP BY ISNULL(clerk_names.name,mc.type) -HAVING SUM(pages_kb) >= 1024 -OPTION( RECOMPILE ); +HAVING SUM({pages_kb}) >= 1024 +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 @@ -368,13 +374,12 @@ const sqlServerPropertiesV2 = `DECLARE @sys_info TABLE ( IF OBJECT_ID('master.sys.dm_os_sys_info') IS NOT NULL BEGIN 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 SELECT 'sqlserver_server_properties' As [measurement], 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 = 1 THEN 1 ELSE 0 END ) AS db_restoring, SUM( CASE WHEN state = 2 THEN 1 ELSE 0 END ) AS db_recovering, @@ -393,7 +398,10 @@ CROSS APPLY ( 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), counter_name nvarchar(128), @@ -413,130 +421,157 @@ SELECT DISTINCT FROM sys.dm_os_performance_counters AS spi WHERE ( counter_name IN ( - 'SQL Compilations/sec', - 'SQL Re-Compilations/sec', - 'User Connections', - 'Batch Requests/sec', - 'Logouts/sec', - 'Logins/sec', - 'Processes blocked', - 'Latch Waits/sec', - 'Full Scans/sec', - 'Index Searches/sec', - 'Page Splits/sec', - 'Page Lookups/sec', - 'Page Reads/sec', - 'Page Writes/sec', - 'Readahead Pages/sec', - 'Lazy Writes/sec', - 'Checkpoint Pages/sec', - 'Page life expectancy', - 'Log File(s) Size (KB)', - 'Log File(s) Used Size (KB)', - 'Data File(s) Size (KB)', - 'Transactions/sec', - 'Write Transactions/sec', - 'Active Temp Tables', - 'Temp Tables Creation Rate', - 'Temp Tables For Destruction', - 'Free Space in tempdb (KB)', - 'Version Store Size (KB)', - 'Memory Grants Pending', - 'Free list stalls/sec', - 'Buffer cache hit ratio', - 'Buffer cache hit ratio base', - 'Backup/Restore Throughput/sec', - 'Total Server Memory (KB)', - 'Target Server Memory (KB)' + "SQL Compilations/sec", + "SQL Re-Compilations/sec", + "User Connections", + "Batch Requests/sec", + "Logouts/sec", + "Logins/sec", + "Processes blocked", + "Latch Waits/sec", + "Full Scans/sec", + "Index Searches/sec", + "Page Splits/sec", + "Page Lookups/sec", + "Page Reads/sec", + "Page Writes/sec", + "Readahead Pages/sec", + "Lazy Writes/sec", + "Checkpoint Pages/sec", + "Page life expectancy", + "Log File(s) Size (KB)", + "Log File(s) Used Size (KB)", + "Data File(s) Size (KB)", + "Transactions/sec", + "Write Transactions/sec", + "Active Temp Tables", + "Temp Tables Creation Rate", + "Temp Tables For Destruction", + "Free Space in tempdb (KB)", + "Version Store Size (KB)", + "Memory Grants Pending", + "Free list stalls/sec", + "Buffer cache hit ratio", + "Buffer cache hit ratio base", + "Backup/Restore Throughput/sec", + "Total Server Memory (KB)", + "Target Server Memory (KB)" ) ) OR ( - instance_name IN ('_Total','Column store object pool') + instance_name IN ("_Total","Column store object pool") AND counter_name IN ( - 'Log Flushes/sec', - 'Log Flush Wait Time', - 'Lock Timeouts/sec', - 'Number of Deadlocks/sec', - 'Lock Waits/sec', - 'Latch Waits/sec', - 'Memory broker clerk size', - 'Log Bytes Flushed/sec', - 'Bytes Sent to Replica/sec', - 'Log Send Queue', - 'Bytes Sent to Transport/sec', - 'Sends to Replica/sec', - 'Bytes Sent to Transport/sec', - 'Sends to Transport/sec', - 'Bytes Received from Replica/sec', - 'Receives from Replica/sec', - 'Flow Control Time (ms/sec)', - 'Flow Control/sec', - 'Resent Messages/sec', - 'Redone Bytes/sec', - 'XTP Memory Used (KB)' + "Log Flushes/sec", + "Log Flush Wait Time", + "Lock Timeouts/sec", + "Number of Deadlocks/sec", + "Lock Waits/sec", + "Latch Waits/sec", + "Memory broker clerk size", + "Log Bytes Flushed/sec", + "Bytes Sent to Replica/sec", + "Log Send Queue", + "Bytes Sent to Transport/sec", + "Sends to Replica/sec", + "Bytes Sent to Transport/sec", + "Sends to Transport/sec", + "Bytes Received from Replica/sec", + "Receives from Replica/sec", + "Flow Control Time (ms/sec)", + "Flow Control/sec", + "Resent Messages/sec", + "Redone Bytes/sec", + "XTP Memory Used (KB)" ) OR ( - object_name = 'SQLServer:Database Replica' - AND counter_name IN ( - 'Log Bytes Received/sec', - 'Log Apply Pending Queue', - 'Redone Bytes/sec', - 'Recovery Queue', - 'Log Apply Ready Queue' + counter_name IN ( + "Log Bytes Received/sec", + "Log Apply Pending Queue", + "Redone Bytes/sec", + "Recovery Queue", + "Log Apply Ready Queue" ) - AND instance_name = '_Total' + AND instance_name = "_Total" ) ) OR ( - object_name = 'SQLServer:Database Replica' - AND counter_name IN ('Transaction Delay') + counter_name IN ("Transaction Delay") ) OR ( - object_name = 'SQLServer:Workload Group Stats' - AND counter_name IN ( - 'CPU usage %', - 'CPU usage % base', - 'Queued requests', - 'Requests completed/sec', - 'Blocked tasks' + counter_name IN ( + "CPU usage %", + "CPU usage % base", + "Queued requests", + "Requests completed/sec", + "Blocked tasks" ) ) OR ( - object_name = 'SQLServer:Resource Pool Stats' - AND counter_name IN ( - 'Active memory grant amount (KB)', - 'Disk Read Bytes/sec', - 'Disk Read IO Throttled/sec', - 'Disk Read IO/sec', - 'Disk Write Bytes/sec', - 'Disk Write IO Throttled/sec', - 'Disk Write IO/sec', - 'Used memory (KB)' + counter_name IN ( + "Active memory grant amount (KB)", + "Disk Read Bytes/sec", + "Disk Read IO Throttled/sec", + "Disk Read IO/sec", + "Disk Write Bytes/sec", + "Disk Write IO Throttled/sec", + "Disk Write IO/sec", + "Used memory (KB)" ) - ) OR object_name IN ( - 'SQLServer:User Settable', - 'SQLServer:SQL Errors' + ) OR ( + object_name LIKE "%User Settable%" + OR object_name LIKE "%SQL Errors%" ) +' +,'"','''') -SELECT 'sqlserver_performance' AS [measurement], - REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], - SERVERPROPERTY('ServerName') AS [host], +SET @DynamicPerf += REPLACE(' +SELECT "sqlserver_performance" AS [measurement], + REPLACE(@@SERVERNAME,"\",":") AS [sql_instance], pc.object_name AS [object], 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] FROM @PCounters AS pc LEFT OUTER JOIN @PCounters AS pc1 ON ( - pc.counter_name = REPLACE(pc1.counter_name,' base','') - OR pc.counter_name = REPLACE(pc1.counter_name,' base',' (ms)') + pc.counter_name = REPLACE(pc1.counter_name," base","") + OR pc.counter_name = REPLACE(pc1.counter_name," base"," (ms)") ) AND pc.object_name = pc1.object_name AND pc.instance_name = pc1.instance_name - AND pc1.counter_name LIKE '%base' -WHERE pc.counter_name NOT LIKE '% base' -OPTION( RECOMPILE ); + AND pc1.counter_name LIKE "%base" +WHERE pc.counter_name NOT LIKE "% base" +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 'sqlserver_waitstats' AS [measurement], REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], -SERVERPROPERTY('ServerName') AS [host], ws.wait_type, wait_time_ms, wait_time_ms - signal_wait_time_ms AS [resource_wait_ms], @@ -1098,7 +1133,6 @@ BEGIN SELECT TOP(1) 'sqlserver_azurestats' AS [measurement], REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], - SERVERPROPERTY('ServerName') AS [host], avg_cpu_percent, avg_data_io_percent, avg_log_write_percent,