From ff40da6019a2094facb3cde74a401a4aaa8edb2a Mon Sep 17 00:00:00 2001
From: Mark Wilkinson - m82labs <mark@m82labs.com>
Date: Fri, 6 Apr 2018 17:58:33 -0400
Subject: [PATCH] Use explicit casts to avoid datatype issues (#3980)

---
 plugins/inputs/sqlserver/sqlserver.go | 216 +++++++++++++-------------
 1 file changed, 106 insertions(+), 110 deletions(-)

diff --git a/plugins/inputs/sqlserver/sqlserver.go b/plugins/inputs/sqlserver/sqlserver.go
index 5196cc33..41a8b7ec 100644
--- a/plugins/inputs/sqlserver/sqlserver.go
+++ b/plugins/inputs/sqlserver/sqlserver.go
@@ -397,9 +397,7 @@ CROSS APPLY (
 OPTION( RECOMPILE );
 `
 
-const sqlPerformanceCountersV2 string = `DECLARE @DynamicPerf NVARCHAR(MAX) = ''
-
-SET @DynamicPerf += REPLACE('
+const sqlPerformanceCountersV2 string = `
 DECLARE @PCounters TABLE
 (
 	object_name nvarchar(128),
@@ -409,140 +407,120 @@ DECLARE @PCounters TABLE
 	cntr_type INT,
 	Primary Key(object_name, counter_name, instance_name)
 );
-
 INSERT	INTO @PCounters
 SELECT	DISTINCT
 		RTrim(spi.object_name) object_name,
 		RTrim(spi.counter_name) counter_name,
 		RTrim(spi.instance_name) instance_name,
-		spi.cntr_value,
+		CAST(spi.cntr_value AS BIGINT) AS cntr_value,
 		spi.cntr_type
 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 ( 
 				counter_name IN (
-					"Log Bytes Received/sec",
-					"Log Apply Pending Queue",
-					"Redone Bytes/sec",
-					"Recovery Queue",
-					"Log Apply Ready Queue"
+					'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 (
-			counter_name IN ("Transaction Delay")
+			counter_name IN ('Transaction Delay')
 		) OR (
 			counter_name IN (
-				"CPU usage %",
-				"CPU usage % base",
-				"Queued requests",
-				"Requests completed/sec",
-				"Blocked tasks"
+				'CPU usage %',
+				'CPU usage % base',
+				'Queued requests',
+				'Requests completed/sec',
+				'Blocked tasks'
 			)
 		) OR (
 			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)"
+				'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 LIKE "%User Settable%"
-			OR object_name LIKE "%SQL Errors%"
+			object_name LIKE '%User Settable%'
+			OR object_name LIKE '%SQL Errors%'
 		)
-'
-,'"','''')
 
-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 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)")
-			)
-			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"
-UNION ALL
+DECLARE @SQL NVARCHAR(MAX)
+SET  @SQL = REPLACE('
 SELECT
-"sqlserver_performance" As [measurement],
-REPLACE(@@SERVERNAME,"\",":") AS [sql_instance],
 "SQLServer:Workload Group Stats" AS object,
 counter,
 instance,
-vs.value
+CAST(vs.value AS BIGINT) AS value,
+1
 FROM
 (
     SELECT 
@@ -561,11 +539,29 @@ FROM
 ) 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);'
+) AS vs'
 ,'"','''')
 
-EXEC(@DynamicPerf)
+INSERT INTO @PCounters
+EXEC( @SQL )
+
+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],
+		CAST(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 float(10)) 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)')
+			)
+			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);
 `
 
 const sqlWaitStatsCategorizedV2 string = `SELECT
-- 
GitLab