Improve Azure Managed Instance support + more in sqlserver input (#4642)

This commit is contained in:
Mark Wilkinson - m82labs 2018-09-11 21:47:30 -04:00 committed by Daniel Nelson
parent 6a60e3f9ff
commit b43165f2d8
4 changed files with 211 additions and 117 deletions

35
Gopkg.lock generated
View File

@ -1,6 +1,14 @@
# This file is autogenerated, do not edit; changes may be undone by the next 'dep ensure'.
[[projects]]
digest = "1:972f38a9c879a4920d1e3a3d3438104b6c06163bfa3e6f4064adb00468d40587"
name = "cloud.google.com/go"
packages = ["civil"]
pruneopts = ""
revision = "c728a003b238b26cef9ab6753a5dc424b331c3ad"
version = "v0.27.0"
[[projects]]
branch = "master"
digest = "1:fc0802104acded1f48e4860a9f2db85b82b4a754fca9eae750ff4e8b8cdf2116"
@ -122,7 +130,7 @@
[[projects]]
branch = "master"
digest = "1:0828d8c0f95689f832cf348fe23827feb7640cd698d612ef59e2f9d041f54c68"
digest = "1:5a5f28fcfe3a74247733a31ceaac0e53bfc2723e43c596b2e3f110eda9378575"
name = "github.com/apache/thrift"
packages = ["lib/go/thrift"]
pruneopts = ""
@ -230,6 +238,17 @@
revision = "346938d642f2ec3594ed81d874461961cd0faa76"
version = "v1.1.0"
[[projects]]
branch = "master"
digest = "1:7fdc54859cd901c25b9d8db964410a4e0d98fa0dca267fe4cf49c0eede5e06c2"
name = "github.com/denisenkom/go-mssqldb"
packages = [
".",
"internal/cp",
]
pruneopts = ""
revision = "1eb28afdf9b6e56cf673badd47545f844fe81103"
[[projects]]
digest = "1:6098222470fe0172157ce9bbef5d2200df4edde17ee649c5d6e48330e4afa4c6"
name = "github.com/dgrijalva/jwt-go"
@ -257,7 +276,7 @@
revision = "edc3ab29cdff8694dd6feb85cfeb4b5f1b38ed9c"
[[projects]]
digest = "1:d149605f1b00713fdc48150122892d77d49d30c825f690dd92f497aeb6cf18f5"
digest = "1:d2ca9295cce7d0e7b26b498c6b59ff903d8315e8ead97f0f6cadf9e7d613e1e8"
name = "github.com/docker/docker"
packages = [
"api",
@ -498,7 +517,7 @@
[[projects]]
branch = "master"
digest = "1:ff65bf6fc4d1116f94ac305342725c21b55c16819c2606adc8f527755716937f"
digest = "1:e1c91a91cc738cebecbf12fc98f554f6f932c8b97e2052ad63ea43948df5bcb0"
name = "github.com/hashicorp/go-rootcerts"
packages = ["."]
pruneopts = ""
@ -1016,14 +1035,6 @@
pruneopts = ""
revision = "46796da1b0b4794e1e341883a399f12cc7574b55"
[[projects]]
branch = "master"
digest = "1:2fcfc6c3fb8dfe0d80d7789272230d3ac7db15022b66817113f98d9fff880225"
name = "github.com/zensqlmonitor/go-mssqldb"
packages = ["."]
pruneopts = ""
revision = "e8fbf836e44e86764eba398361d1825651709547"
[[projects]]
branch = "master"
digest = "1:0773b5c3be42874166670a20aa177872edb450cd9fc70b1df97303d977702a50"
@ -1312,6 +1323,7 @@
"github.com/aws/aws-sdk-go/service/sts",
"github.com/bsm/sarama-cluster",
"github.com/couchbase/go-couchbase",
"github.com/denisenkom/go-mssqldb",
"github.com/dgrijalva/jwt-go",
"github.com/docker/docker/api/types",
"github.com/docker/docker/api/types/container",
@ -1375,7 +1387,6 @@
"github.com/vmware/govmomi/vim25/soap",
"github.com/vmware/govmomi/vim25/types",
"github.com/wvanbergen/kafka/consumergroup",
"github.com/zensqlmonitor/go-mssqldb",
"golang.org/x/net/context",
"golang.org/x/net/html/charset",
"golang.org/x/oauth2",

View File

@ -183,7 +183,7 @@
branch = "master"
[[constraint]]
name = "github.com/zensqlmonitor/go-mssqldb"
name = "github.com/denisenkom/go-mssqldb"
branch = "master"
[[constraint]]

View File

@ -90,7 +90,17 @@ The new (version 2) metrics provide:
- *TempDB*: Free space, Version store usage, Active temp tables, temp table creation rate, + more
- *Resource Governor*: CPU Usage, Requests/sec, Queued Requests, and Blocked tasks per workload group + more
- *Server properties*: Number of databases in all possible states (online, offline, suspect, etc.), cpu count, physical memory, SQL Server service uptime, and SQL Server version
- *Wait stats*: Wait time in ms, number of waiting tasks, resource wait time, signal wait time, max wait time in ms, wait type, and wait category. The waits are categorized using the sasme categories used in Query Store.
- *Wait stats*: Wait time in ms, number of waiting tasks, resource wait time, signal wait time, max wait time in ms, wait type, and wait category. The waits are categorized using the same categories used in Query Store.
- *Azure Managed Instances*
- Stats from `sys.server_resource_stats`:
- cpu_count
- server_memory
- sku
- engine_edition
- hardware_type
- total_storage_mb
- available_storage_mb
- uptime
The following metrics can be used directly, with no delta calculations:
- SQLServer:Buffer Manager\Buffer cache hit ratio
@ -129,5 +139,4 @@ 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:
- `sql_instance`: Physical host and instance name (hostname:instance)
- `sql_instance`: Physical host and instance name (hostname:instance)

View File

@ -9,7 +9,7 @@ import (
"github.com/influxdata/telegraf/plugins/inputs"
// go-mssqldb initialization
_ "github.com/zensqlmonitor/go-mssqldb"
_ "github.com/denisenkom/go-mssqldb"
)
// SQLServer struct
@ -348,7 +348,9 @@ ELSE
EXEC(@SQL)
`
const sqlDatabaseIOV2 = `SELECT
const sqlDatabaseIOV2 = `IF SERVERPROPERTY('EngineEdition') = 5
BEGIN
SELECT
'sqlserver_database_io' As [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
DB_NAME([vfs].[database_id]) [database_name],
@ -358,43 +360,123 @@ vfs.num_of_bytes_read AS read_bytes,
vfs.io_stall_write_ms AS write_latency_ms,
vfs.num_of_writes AS writes,
vfs.num_of_bytes_written AS write_bytes,
CASE WHEN vfs.file_id = 2 THEN 'LOG' ELSE 'ROWS' END AS file_type
b.name as logical_filename,
b.physical_name as physical_filename,
CASE WHEN vfs.file_id = 2 THEN 'LOG' ELSE 'DATA' END AS file_type
FROM
[sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs
OPTION( RECOMPILE );
inner join sys.database_files b on b.file_id = vfs.file_id
END
ELSE
BEGIN
SELECT
'sqlserver_database_io' As [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
DB_NAME([vfs].[database_id]) [database_name],
vfs.io_stall_read_ms AS read_latency_ms,
vfs.num_of_reads AS reads,
vfs.num_of_bytes_read AS read_bytes,
vfs.io_stall_write_ms AS write_latency_ms,
vfs.num_of_writes AS writes,
vfs.num_of_bytes_written AS write_bytes,
b.name as logical_filename,
b.physical_name as physical_filename,
CASE WHEN vfs.file_id = 2 THEN 'LOG' ELSE 'DATA' END AS file_type
FROM
[sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs
inner join sys.master_files b on b.database_id = vfs.database_id and b.file_id = vfs.file_id
END
`
const sqlServerPropertiesV2 = `DECLARE @sys_info TABLE (
cpu_count INT,
server_memory INT,
server_memory BIGINT,
sku NVARCHAR(64),
engine_edition SMALLINT,
hardware_type VARCHAR(15),
total_storage_mb BIGINT,
available_storage_mb BIGINT,
uptime INT
)
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, (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
IF SERVERPROPERTY('EngineEdition') = 8 -- Managed Instance
INSERT INTO @sys_info ( cpu_count, server_memory, sku, engine_edition, hardware_type, total_storage_mb, available_storage_mb, uptime )
SELECT TOP(1)
virtual_core_count AS cpu_count,
(SELECT process_memory_limit_mb FROM sys.dm_os_job_object) AS server_memory,
sku,
cast(SERVERPROPERTY('EngineEdition') as smallint) AS engine_edition,
hardware_generation AS hardware_type,
reserved_storage_mb AS total_storage_mb,
(reserved_storage_mb - storage_space_used_mb) AS available_storage_mb,
(select DATEDIFF(MINUTE,sqlserver_start_time,GETDATE()) from sys.dm_os_sys_info) as uptime
FROM sys.server_resource_stats
ORDER BY start_time DESC
SELECT
'sqlserver_server_properties' As [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
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,
SUM( CASE WHEN state = 3 THEN 1 ELSE 0 END ) AS db_recoveryPending,
SUM( CASE WHEN state = 4 THEN 1 ELSE 0 END ) AS db_suspect,
SUM( CASE WHEN state = 10 THEN 1 ELSE 0 END ) AS db_offline,
MAX( sinfo.cpu_count ) AS cpu_count,
MAX( sinfo.server_memory ) AS server_memory,
MAX( sinfo.uptime ) AS uptime,
SERVERPROPERTY('ProductVersion') AS sql_version
FROM sys.databases
CROSS APPLY (
SELECT *
FROM @sys_info
) AS sinfo
OPTION( RECOMPILE );
ELSE
BEGIN
DECLARE @total_disk_size_mb BIGINT,
@available_space_mb BIGINT
SELECT @total_disk_size_mb = sum(total_disk_size_mb),
@available_space_mb = sum(free_disk_space_mb)
FROM (
SELECT distinct logical_volume_name AS LogicalName,
total_bytes/(1024*1024)as total_disk_size_mb,
available_bytes /(1024*1024) free_disk_space_mb
FROM sys.master_files AS f
CROSS APPLY sys.dm_os_volume_stats(f.database_id, f.file_id)
) as osVolumes
INSERT INTO @sys_info ( cpu_count, server_memory, sku, engine_edition, hardware_type, total_storage_mb, available_storage_mb, uptime )
SELECT cpu_count,
(SELECT total_physical_memory_kb FROM sys.dm_os_sys_memory) AS server_memory,
CAST(SERVERPROPERTY('Edition') AS NVARCHAR(64)) as sku,
CAST(SERVERPROPERTY('EngineEdition') as smallint) as engine_edition,
CASE virtual_machine_type_desc
WHEN 'NONE' THEN 'PHYSICAL Machine'
ELSE virtual_machine_type_desc
END AS hardware_type,
@total_disk_size_mb,
@available_space_mb,
DATEDIFF(MINUTE,sqlserver_start_time,GETDATE())
FROM sys.dm_os_sys_info
END
END
SELECT 'sqlserver_server_properties' AS [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
s.cpu_count,
s.server_memory,
s.sku,
s.engine_edition,
s.hardware_type,
s.total_storage_mb,
s.available_storage_mb,
s.uptime,
db_online,
db_restoring,
db_recovering,
db_recoveryPending,
db_suspect,
db_offline
FROM (
SELECT 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,
SUM( CASE WHEN state = 3 THEN 1 ELSE 0 END ) AS db_recoveryPending,
SUM( CASE WHEN state = 4 THEN 1 ELSE 0 END ) AS db_suspect,
SUM( CASE WHEN state = 10 THEN 1 ELSE 0 END ) AS db_offline
FROM sys.databases
) AS dbs
CROSS APPLY (
SELECT cpu_count, server_memory, sku, engine_edition, hardware_type, total_storage_mb, available_storage_mb, uptime
FROM @sys_info
) AS s
OPTION( RECOMPILE )
`
const sqlPerformanceCountersV2 string = `
@ -416,53 +498,45 @@ SELECT DISTINCT
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)',
'Forwarded Recs/sec'
)
) OR (
instance_name IN ('_Total','Column store object pool')
AND counter_name IN (
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',
'Memory Grants Outstanding',
'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)',
'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',
@ -477,29 +551,18 @@ WHERE (
'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'
)
AND instance_name = '_Total'
)
) OR (
counter_name IN ('Transaction Delay')
) OR (
counter_name IN (
'XTP Memory Used (KB)',
'Transaction Delay',
'Log Bytes Received/sec',
'Log Apply Pending Queue',
'Redone Bytes/sec',
'Recovery Queue',
'Log Apply Ready Queue',
'CPU usage %',
'CPU usage % base',
'Queued requests',
'Requests completed/sec',
'Blocked tasks'
)
) OR (
counter_name IN (
'Blocked tasks',
'Active memory grant amount (KB)',
'Disk Read Bytes/sec',
'Disk Read IO Throttled/sec',
@ -507,11 +570,22 @@ WHERE (
'Disk Write Bytes/sec',
'Disk Write IO Throttled/sec',
'Disk Write IO/sec',
'Used memory (KB)'
'Used memory (KB)',
'Forwarded Recs/sec',
'Background Writer pages/sec',
'Percent Log Used'
)
) OR (
) OR (
object_name LIKE '%User Settable%'
OR object_name LIKE '%SQL Errors%'
) OR (
instance_name IN ('_Total')
AND counter_name IN (
'Lock Timeouts/sec',
'Number of Deadlocks/sec',
'Lock Waits/sec',
'Latch Waits/sec'
)
)
DECLARE @SQL NVARCHAR(MAX)
@ -617,6 +691,7 @@ LEFT OUTER JOIN ( VALUES
('CMEMPARTITIONED','Memory'),
('CMEMTHREAD','Memory'),
('CXPACKET','Parallelism'),
('CXCONSUMER','Parallelism'),
('DBMIRROR_DBM_EVENT','Mirroring'),
('DBMIRROR_DBM_MUTEX','Mirroring'),
('DBMIRROR_EVENTS_QUEUE','Mirroring'),
@ -1098,10 +1173,8 @@ ws.wait_type NOT IN (
N'PARALLEL_REDO_WORKER_WAIT_WORK',
N'PREEMPTIVE_HADR_LEASE_MECHANISM', N'PREEMPTIVE_SP_SERVER_DIAGNOSTICS',
N'PREEMPTIVE_OS_LIBRARYOPS', N'PREEMPTIVE_OS_COMOPS', N'PREEMPTIVE_OS_CRYPTOPS',
N'PREEMPTIVE_OS_PIPEOPS', N'PREEMPTIVE_OS_AUTHENTICATIONOPS',
N'PREEMPTIVE_OS_GENERICOPS', N'PREEMPTIVE_OS_VERIFYTRUST',
N'PREEMPTIVE_OS_FILEOPS', N'PREEMPTIVE_OS_DEVICEOPS', N'PREEMPTIVE_OS_QUERYREGISTRY',
N'PREEMPTIVE_OS_WRITEFILE',
N'PREEMPTIVE_OS_PIPEOPS','PREEMPTIVE_OS_GENERICOPS', N'PREEMPTIVE_OS_VERIFYTRUST',
N'PREEMPTIVE_OS_DEVICEOPS',
N'PREEMPTIVE_XE_CALLBACKEXECUTE', N'PREEMPTIVE_XE_DISPATCHER',
N'PREEMPTIVE_XE_GETTARGETSTATE', N'PREEMPTIVE_XE_SESSIONCOMMIT',
N'PREEMPTIVE_XE_TARGETINIT', N'PREEMPTIVE_XE_TARGETFINALIZE',
@ -1113,14 +1186,15 @@ ws.wait_type NOT IN (
N'SLEEP_DCOMSTARTUP', N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY',
N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', N'SLEEP_SYSTEMTASK', N'SLEEP_TASK',
N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', N'SP_SERVER_DIAGNOSTICS_SLEEP',
N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', N'SQLTRACE_WAIT_ENTRIES',
N'SQLTRACE_BUFFER_FLUSH', N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
N'SQLTRACE_WAIT_ENTRIES',
N'WAIT_FOR_RESULTS', N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', N'WAIT_XTP_HOST_WAIT',
N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', N'WAIT_XTP_CKPT_CLOSE',
N'XE_BUFFERMGR_ALLPROCESSED_EVENT', N'XE_DISPATCHER_JOIN',
N'XE_DISPATCHER_WAIT', N'XE_LIVE_TARGET_TVF', N'XE_TIMER_EVENT')
N'XE_DISPATCHER_WAIT', N'XE_LIVE_TARGET_TVF', N'XE_TIMER_EVENT',
N'SOS_WORK_DISPATCHER','RESERVED_MEMORY_ALLOCATION_EXT')
AND waiting_tasks_count > 0
ORDER BY
waiting_tasks_count DESC
AND wait_time_ms > 100
OPTION (RECOMPILE);
`