From b4e14abe0806e0f82fbbaf54c06b37b447e5bad6 Mon Sep 17 00:00:00 2001 From: Niko Feng Date: Wed, 10 May 2023 09:48:22 +0000 Subject: [PATCH 1/2] Add Azure Arc-enabled SQL MI support --- plugins/inputs/sqlserver/README.md | 5 + .../inputs/sqlserver/azurearcsqlmiqueries.go | 515 ++++++++++++++++++ .../sqlserver/azurearcsqlmiqueries_test.go | 312 +++++++++++ plugins/inputs/sqlserver/sample.conf | 4 + plugins/inputs/sqlserver/sqlserver.go | 19 +- 5 files changed, 851 insertions(+), 4 deletions(-) create mode 100644 plugins/inputs/sqlserver/azurearcsqlmiqueries.go create mode 100644 plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go diff --git a/plugins/inputs/sqlserver/README.md b/plugins/inputs/sqlserver/README.md index c066434f8fcd5..3cd06828dbb88 100644 --- a/plugins/inputs/sqlserver/README.md +++ b/plugins/inputs/sqlserver/README.md @@ -12,6 +12,7 @@ supplied by SQL Server. - Azure SQL Database (Single) - Azure SQL Managed Instance - Azure SQL Elastic Pool +- Azure Arc-enabled SQL Managed Instance ## Additional Setup @@ -179,6 +180,10 @@ to use them. ## AzureSQLPoolResourceStats, AzureSQLPoolResourceGovernance, AzureSQLPoolDatabaseIO, AzureSQLPoolWaitStats, ## AzureSQLPoolMemoryClerks, AzureSQLPoolPerformanceCounters, AzureSQLPoolSchedulers + ## Queries enabled by default for database_type = "AzureArcSQLManagedInstance" are - + ## AzureSQLMIDatabaseIO, AzureSQLMIServerProperties, AzureSQLMIOsWaitstats, + ## AzureSQLMIMemoryClerks, AzureSQLMIPerformanceCounters, AzureSQLMIRequests, AzureSQLMISchedulers + ## Following are old config settings ## You may use them only if you are using the earlier flavor of queries, however it is recommended to use ## the new mechanism of identifying the database_type there by use it's corresponding queries diff --git a/plugins/inputs/sqlserver/azurearcsqlmiqueries.go b/plugins/inputs/sqlserver/azurearcsqlmiqueries.go new file mode 100644 index 0000000000000..6883b4590f0a2 --- /dev/null +++ b/plugins/inputs/sqlserver/azurearcsqlmiqueries.go @@ -0,0 +1,515 @@ +//nolint:lll // conditionally long lines allowed +package sqlserver + +import ( + _ "github.com/denisenkom/go-mssqldb" // go-mssqldb initialization +) + +// ------------------------------------------------------------------------------------------------ +// ------------------ Azure Arc Managed Instance ------------------------------------------------------ +// ------------------------------------------------------------------------------------------------ +const sqlAzureArcMIProperties = ` +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +SELECT TOP 1 + 'sqlserver_server_properties' AS [measurement] + ,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance] + ,(SELECT [cpu_count] FROM sys.dm_os_sys_info) AS [cpu_count] + ,(SELECT [physical_memory_kb] FROM sys.dm_os_sys_info) AS [server_memory] + ,(SELECT [host_sku] FROM sys.dm_os_host_info) AS [sku] + ,SERVERPROPERTY('EngineEdition') AS [engine_edition] + ,(SELECT [container_type_desc] FROM sys.dm_os_sys_info) AS [hardware_type] + ,(SELECT DATEDIFF(MINUTE,[sqlserver_start_time],GETDATE()) FROM sys.dm_os_sys_info) as [uptime] + ,SERVERPROPERTY('ProductVersion') AS [sql_version] + ,LEFT(@@VERSION,CHARINDEX(' - ',@@VERSION)) AS [sql_version_desc] + ,(SELECT SUM( CASE WHEN [state] = 0 THEN 1 ELSE 0 END ) FROM sys.databases) AS [db_online] + ,(SELECT SUM( CASE WHEN [state] = 1 THEN 1 ELSE 0 END ) FROM sys.databases) AS [db_restoring] + ,(SELECT SUM( CASE WHEN [state] = 2 THEN 1 ELSE 0 END ) FROM sys.databases) AS [db_recovering] + ,(SELECT SUM( CASE WHEN [state] = 3 THEN 1 ELSE 0 END ) FROM sys.databases) AS [db_recoveryPending] + ,(SELECT SUM( CASE WHEN [state] = 4 THEN 1 ELSE 0 END ) FROM sys.databases) AS [db_suspect] + ,(SELECT SUM( CASE WHEN [state] IN (6,10) THEN 1 ELSE 0 END) FROM sys.databases) AS [db_offline] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability +` + +const sqlAzureArcMIDatabaseIO = ` +SET DEADLOCK_PRIORITY -10; +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +SELECT + 'sqlserver_database_io' AS [measurement] + ,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance] + ,DB_NAME(mf.[database_id]) AS [database_name] + ,COALESCE(mf.[physical_name],'RBPEX') AS [physical_filename] --RPBEX = Resilient Buffer Pool Extension + ,COALESCE(mf.[name],'RBPEX') AS [logical_filename] --RPBEX = Resilient Buffer Pool Extension + ,mf.[type_desc] AS [file_type] + ,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] + ,vfs.io_stall_queued_read_ms AS [rg_read_stall_ms] + ,vfs.io_stall_queued_write_ms AS [rg_write_stall_ms] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability +FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs +LEFT OUTER JOIN sys.master_files AS mf WITH (NOLOCK) + ON vfs.[database_id] = mf.[database_id] + AND vfs.[file_id] = mf.[file_id] +WHERE + vfs.[database_id] < 32760 +` + +const sqlAzureArcMIMemoryClerks = ` +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +SELECT + 'sqlserver_memory_clerks' AS [measurement] + ,REPLACE(@@SERVERNAME, '\', ':') AS [sql_instance] + ,mc.[type] AS [clerk_type] + ,SUM(mc.[pages_kb]) AS [size_kb] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability +FROM sys.[dm_os_memory_clerks] AS mc WITH (NOLOCK) +GROUP BY + mc.[type] +HAVING + SUM(mc.[pages_kb]) >= 1024 +OPTION(RECOMPILE); +` + +const sqlAzureArcMIOsWaitStats = ` +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +SELECT + 'sqlserver_waitstats' AS [measurement] + ,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance] + ,ws.[wait_type] + ,[wait_time_ms] + ,[wait_time_ms] - [signal_wait_time_ms] AS [resource_wait_ms] + ,[signal_wait_time_ms] + ,[max_wait_time_ms] + ,[waiting_tasks_count] + ,CASE + WHEN ws.[wait_type] LIKE 'SOS_SCHEDULER_YIELD' then 'CPU' + WHEN ws.[wait_type] = 'THREADPOOL' THEN 'Worker Thread' + WHEN ws.[wait_type] LIKE 'LCK[_]%' THEN 'Lock' + WHEN ws.[wait_type] LIKE 'LATCH[_]%' THEN 'Latch' + WHEN ws.[wait_type] LIKE 'PAGELATCH[_]%' THEN 'Buffer Latch' + WHEN ws.[wait_type] LIKE 'PAGEIOLATCH[_]%' THEN 'Buffer IO' + WHEN ws.[wait_type] LIKE 'RESOURCE_SEMAPHORE_QUERY_COMPILE%' THEN 'Compilation' + WHEN ws.[wait_type] LIKE 'CLR[_]%' or ws.[wait_type] like 'SQLCLR%' THEN 'SQL CLR' + WHEN ws.[wait_type] LIKE 'DBMIRROR_%' THEN 'Mirroring' + WHEN ws.[wait_type] LIKE 'DTC[_]%' or ws.[wait_type] LIKE 'DTCNEW%' or ws.[wait_type] LIKE 'TRAN_%' + or ws.[wait_type] LIKE 'XACT%' or ws.[wait_type] like 'MSQL_XACT%' THEN 'Transaction' + WHEN ws.[wait_type] LIKE 'SLEEP[_]%' + or ws.[wait_type] IN ( + 'LAZYWRITER_SLEEP', 'SQLTRACE_BUFFER_FLUSH', 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', + 'SQLTRACE_WAIT_ENTRIES', 'FT_IFTS_SCHEDULER_IDLE_WAIT', 'XE_DISPATCHER_WAIT', + 'REQUEST_FOR_DEADLOCK_SEARCH', 'LOGMGR_QUEUE', 'ONDEMAND_TASK_QUEUE', + 'CHECKPOINT_QUEUE', 'XE_TIMER_EVENT') THEN 'Idle' + WHEN ws.[wait_type] IN( + 'ASYNC_IO_COMPLETION','BACKUPIO','CHKPT','WRITE_COMPLETION', + 'IO_QUEUE_LIMIT', 'IO_RETRY') THEN 'Other Disk IO' + WHEN ws.[wait_type] LIKE 'PREEMPTIVE_%' THEN 'Preemptive' + WHEN ws.[wait_type] LIKE 'BROKER[_]%' THEN 'Service Broker' + WHEN ws.[wait_type] IN ( + 'WRITELOG','LOGBUFFER','LOGMGR_RESERVE_APPEND', + 'LOGMGR_FLUSH', 'LOGMGR_PMM_LOG') THEN 'Tran Log IO' + WHEN ws.[wait_type] LIKE 'LOG_RATE%' then 'Log Rate Governor' + WHEN ws.[wait_type] LIKE 'HADR_THROTTLE[_]%' + or ws.[wait_type] = 'THROTTLE_LOG_RATE_LOG_STORAGE' THEN 'HADR Log Rate Governor' + WHEN ws.[wait_type] LIKE 'RBIO_RG%' or ws.[wait_type] like 'WAIT_RBIO_RG%' then 'VLDB Log Rate Governor' + WHEN ws.[wait_type] LIKE 'RBIO[_]%' or ws.[wait_type] like 'WAIT_RBIO[_]%' then 'VLDB RBIO' + WHEN ws.[wait_type] IN( + 'ASYNC_NETWORK_IO','EXTERNAL_SCRIPT_NETWORK_IOF', + 'NET_WAITFOR_PACKET','PROXY_NETWORK_IO') THEN 'Network IO' + WHEN ws.[wait_type] IN ( 'CXPACKET', 'CXCONSUMER') + or ws.[wait_type] like 'HT%' or ws.[wait_type] like 'BMP%' + or ws.[wait_type] like 'BP%' THEN 'Parallelism' + WHEN ws.[wait_type] IN( + 'CMEMTHREAD','CMEMPARTITIONED','EE_PMOLOCK','EXCHANGE', + 'RESOURCE_SEMAPHORE','MEMORY_ALLOCATION_EXT', + 'RESERVED_MEMORY_ALLOCATION_EXT', 'MEMORY_GRANT_UPDATE') THEN 'Memory' + WHEN ws.[wait_type] IN ('WAITFOR','WAIT_FOR_RESULTS') THEN 'User Wait' + WHEN ws.[wait_type] LIKE 'HADR[_]%' or ws.[wait_type] LIKE 'PWAIT_HADR%' + or ws.[wait_type] LIKE 'REPLICA[_]%' or ws.[wait_type] LIKE 'REPL_%' + or ws.[wait_type] LIKE 'SE_REPL[_]%' + or ws.[wait_type] LIKE 'FCB_REPLICA%' THEN 'Replication' + WHEN ws.[wait_type] LIKE 'SQLTRACE[_]%' + or ws.[wait_type] IN ( + 'TRACEWRITE', 'SQLTRACE_LOCK', 'SQLTRACE_FILE_BUFFER', 'SQLTRACE_FILE_WRITE_IO_COMPLETION', + 'SQLTRACE_FILE_READ_IO_COMPLETION', 'SQLTRACE_PENDING_BUFFER_WRITERS', 'SQLTRACE_SHUTDOWN', + 'QUERY_TRACEOUT', 'TRACE_EVTNOTIF') THEN 'Tracing' + WHEN ws.[wait_type] IN ( + 'FT_RESTART_CRAWL', 'FULLTEXT GATHERER', 'MSSEARCH', 'FT_METADATA_MUTEX', + 'FT_IFTSHC_MUTEX', 'FT_IFTSISM_MUTEX', 'FT_IFTS_RWLOCK', 'FT_COMPROWSET_RWLOCK', + 'FT_MASTER_MERGE', 'FT_PROPERTYLIST_CACHE', 'FT_MASTER_MERGE_COORDINATOR', + 'PWAIT_RESOURCE_SEMAPHORE_FT_PARALLEL_QUERY_SYNC') THEN 'Full Text Search' + ELSE 'Other' + END as [wait_category] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability +FROM sys.dm_os_wait_stats AS ws WITH (NOLOCK) +WHERE + ws.[wait_type] NOT IN ( + N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', N'BROKER_TASK_STOP', + N'BROKER_TO_FLUSH', N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', + N'CHKPT', N'CLR_AUTO_EVENT', N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', + N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', N'DBMIRROR_QUEUE', + N'DBMIRRORING_CMD', N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', + N'EXECSYNC', N'FSAGENT', N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', + N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', N'HADR_LOGCAPTURE_WAIT', + N'HADR_NOTIFICATION_DEQUEUE', N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', + N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', N'LOGMGR_QUEUE', + N'MEMORY_ALLOCATION_EXT', N'ONDEMAND_TASK_QUEUE', + 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','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', + N'PWAIT_ALL_COMPONENTS_INITIALIZED', N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', + N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', + N'QDS_ASYNC_QUEUE', + N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', N'REQUEST_FOR_DEADLOCK_SEARCH', + N'RESOURCE_QUEUE', N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', N'SLEEP_DBSTARTUP', + 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'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'SOS_WORK_DISPATCHER','RESERVED_MEMORY_ALLOCATION_EXT','SQLTRACE_WAIT_ENTRIES', + N'RBIO_COMM_RETRY') +AND [waiting_tasks_count] > 10 +AND [wait_time_ms] > 100; +` + +const sqlAzureArcMIPerformanceCounters = ` +SET DEADLOCK_PRIORITY -10; +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +DECLARE @PCounters TABLE +( + [object_name] nvarchar(128), + [counter_name] nvarchar(128), + [instance_name] nvarchar(128), + [cntr_value] bigint, + [cntr_type] INT , + Primary Key([object_name],[counter_name],[instance_name]) +); + +WITH PerfCounters AS ( + SELECT DISTINCT + RTrim(spi.[object_name]) [object_name] + ,RTrim(spi.[counter_name]) [counter_name] + ,CASE WHEN ( + RTRIM(spi.[object_name]) LIKE '%:Databases' + OR RTRIM(spi.[object_name]) LIKE '%:Database Replica' + OR RTRIM(spi.[object_name]) LIKE '%:Catalog Metadata' + OR RTRIM(spi.[object_name]) LIKE '%:Query Store' + OR RTRIM(spi.[object_name]) LIKE '%:Columnstore' + OR RTRIM(spi.[object_name]) LIKE '%:Advanced Analytics') + AND TRY_CONVERT([uniqueidentifier], spi.[instance_name]) IS NOT NULL -- for cloud only + THEN ISNULL(d.[name],RTRIM(spi.instance_name)) -- Elastic Pools counters exist for all databases but sys.databases only has current DB value + WHEN + RTRIM([object_name]) LIKE '%:Availability Replica' + AND TRY_CONVERT([uniqueidentifier], spi.[instance_name]) IS NOT NULL -- for cloud only + THEN ISNULL(d.[name],RTRIM(spi.[instance_name])) + RTRIM(SUBSTRING(spi.[instance_name], 37, LEN(spi.[instance_name]))) + ELSE RTRIM(spi.instance_name) + END AS [instance_name] + ,CAST(spi.[cntr_value] AS BIGINT) AS [cntr_value] + ,spi.[cntr_type] + FROM sys.dm_os_performance_counters AS spi + LEFT JOIN sys.databases AS d + ON LEFT(spi.[instance_name], 36) -- some instance_name values have an additional identifier appended after the GUID + = CASE + /*in SQL DB standalone, physical_database_name for master is the GUID of the user database*/ + WHEN d.[name] = 'master' AND TRY_CONVERT([uniqueidentifier], d.[physical_database_name]) IS NOT NULL + THEN d.[name] + ELSE d.[physical_database_name] + END + 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' + ,'Table Lock Escalations/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 Transactions' + ,'Log Growths' + ,'Active Temp Tables' + ,'Logical Connections' + ,'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' + ,'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)' + ,'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' + ,'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)' + ,'Forwarded Records/sec' + ,'Background Writer pages/sec' + ,'Percent Log Used' + ,'Log Send Queue KB' + ,'Redo Queue KB' + ,'Mirrored Write Transactions/sec' + ,'Group Commit Time' + ,'Group Commits/Sec' + ,'Workfiles Created/sec' + ,'Worktables Created/sec' + ,'Distributed Query' + ,'DTC calls' + ,'Query Store CPU usage' + ) OR ( + spi.[object_name] LIKE '%User Settable%' + OR spi.[object_name] LIKE '%SQL Errors%' + OR spi.[object_name] LIKE '%Batch Resp Statistics%' + ) OR ( + spi.[instance_name] IN ('_Total') + AND spi.[counter_name] IN ( + 'Lock Timeouts/sec' + ,'Lock Timeouts (timeout > 0)/sec' + ,'Number of Deadlocks/sec' + ,'Lock Waits/sec' + ,'Latch Waits/sec' + ) + ) +) + +INSERT INTO @PCounters select * from PerfCounters + +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] + ,cast(pc.[cntr_type] as varchar(25)) as [counter_type] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability +from @PCounters 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 sqlAzureArcMIRequests string = ` +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + + + +BEGIN TRY + SELECT + [measurement],[sql_instance],[database_name],[session_id] + ,ISNULL([request_id],0) AS [request_id] + ,[blocking_session_id],[status],[cpu_time_ms] + ,[total_elapsed_time_ms],[logical_reads],[writes] + ,[command],[wait_time_ms],[wait_type] + ,[wait_resource],[program_name] + ,[host_name],[nt_user_name],[login_name] + ,[transaction_isolation_level],[granted_query_memory_pages],[percent_complete] + ,[statement_text],[objectid],[stmt_object_name] + ,[stmt_db_name],[query_hash],[query_plan_hash] + ,replica_updateability + ,[session_db_name],[open_transaction] + FROM ( + SELECT + 'sqlserver_requests' AS [measurement] + ,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance] + ,DB_NAME() as [database_name] + ,s.[session_id] + ,r.[request_id] + ,DB_NAME(COALESCE(r.[database_id], s.[database_id])) AS [session_db_name] + ,COALESCE(r.[status], s.[status]) AS [status] + ,COALESCE(r.[cpu_time], s.[cpu_time]) AS [cpu_time_ms] + ,COALESCE(r.[total_elapsed_time], s.[total_elapsed_time]) AS [total_elapsed_time_ms] + ,COALESCE(r.[logical_reads], s.[logical_reads]) AS [logical_reads] + ,COALESCE(r.[writes], s.[writes]) AS [writes] + ,r.[command] + ,r.[wait_time] AS [wait_time_ms] + ,r.[wait_type] + ,r.[wait_resource] + ,NULLIF(r.[blocking_session_id],0) AS [blocking_session_id] + ,s.[program_name] + ,s.[host_name] + ,s.[nt_user_name] + ,s.[login_name] + ,COALESCE(r.[open_transaction_count], s.[open_transaction_count]) AS [open_transaction] + ,LEFT (CASE COALESCE(r.[transaction_isolation_level], s.[transaction_isolation_level]) + WHEN 0 THEN '0-Read Committed' + WHEN 1 THEN '1-Read Uncommitted (NOLOCK)' + WHEN 2 THEN '2-Read Committed' + WHEN 3 THEN '3-Repeatable Read' + WHEN 4 THEN '4-Serializable' + WHEN 5 THEN '5-Snapshot' + ELSE CONVERT (varchar(30), r.[transaction_isolation_level]) + '-UNKNOWN' + END, 30) AS [transaction_isolation_level] + ,r.[granted_query_memory] AS [granted_query_memory_pages] + ,r.[percent_complete] + ,SUBSTRING( + qt.[text], + r.[statement_start_offset] / 2 + 1, + (CASE WHEN r.[statement_end_offset] = -1 + THEN DATALENGTH(qt.[text]) + ELSE r.[statement_end_offset] + END - r.[statement_start_offset]) / 2 + 1 + ) AS [statement_text] + ,qt.[objectid] + ,QUOTENAME(OBJECT_SCHEMA_NAME(qt.[objectid], qt.[dbid])) + '.' + QUOTENAME(OBJECT_NAME(qt.[objectid], qt.[dbid])) as [stmt_object_name] + ,DB_NAME(qt.[dbid]) AS [stmt_db_name] + ,CONVERT(varchar(20),r.[query_hash],1) AS [query_hash] + ,CONVERT(varchar(20),r.[query_plan_hash],1) AS [query_plan_hash] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability + ,s.[is_user_process] + ,[blocking_or_blocked] = COUNT(*) OVER(PARTITION BY ISNULL(NULLIF(r.[blocking_session_id], 0),s.[session_id])) + FROM sys.dm_exec_sessions AS s + LEFT OUTER JOIN sys.dm_exec_requests AS r + ON s.[session_id] = r.[session_id] + OUTER APPLY sys.dm_exec_sql_text(r.[sql_handle]) AS qt + ) AS data + WHERE + [blocking_or_blocked] > 1 --Always include blocking or blocked sessions/requests + OR [open_transaction] >= 1 --Always include sessions with open transactions + OR ( + [request_id] IS NOT NULL --A request must exists + AND ( --Always fetch user process (in any state), fetch system process only if active + [is_user_process] = 1 + OR [status] COLLATE Latin1_General_BIN NOT IN ('background', 'sleeping') + ) + AND [session_id] <> @@SPID + ) + OPTION(MAXDOP 1); +END TRY +BEGIN CATCH + IF (ERROR_NUMBER() <> 976) --Avoid possible errors from secondary replica + THROW; +END CATCH +` + +const sqlAzureArcMISchedulers string = ` +IF SERVERPROPERTY('EngineEdition') <> 10 BEGIN /*not Azure Arc-enabled Managed Instance*/ + DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Arc-enabled Managed Instance. Check the database_type parameter in the telegraf configuration.'; + RAISERROR (@ErrorMessage,11,1) + RETURN +END + +SELECT + 'sqlserver_schedulers' AS [measurement] + ,REPLACE(@@SERVERNAME, '\', ':') AS [sql_instance] + ,CAST(s.[scheduler_id] AS VARCHAR(4)) AS [scheduler_id] + ,CAST(s.[cpu_id] AS VARCHAR(4)) AS [cpu_id] + ,s.[is_online] + ,s.[is_idle] + ,s.[preemptive_switches_count] + ,s.[context_switches_count] + ,s.[current_tasks_count] + ,s.[runnable_tasks_count] + ,s.[current_workers_count] + ,s.[active_workers_count] + ,s.[work_queue_count] + ,s.[pending_disk_io_count] + ,s.[load_factor] + ,s.[yield_count] + ,s.[total_cpu_usage_ms] + ,s.[total_scheduler_delay_ms] + ,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability +FROM sys.dm_os_schedulers AS s +` diff --git a/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go b/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go new file mode 100644 index 0000000000000..af38f583d6780 --- /dev/null +++ b/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go @@ -0,0 +1,312 @@ +package sqlserver + +import ( + "os" + "testing" + + "github.com/influxdata/telegraf/config" + "github.com/influxdata/telegraf/testutil" + "github.com/stretchr/testify/require" +) + +func TestAzureSQLIntegration_ArcManaged_DatabaseIO_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("## Queries enabled by default for database_type = \"AzureArcSQLManagedInstance\" are -\n ## AzureArcSQLMIDatabaseIO, AzureArcSQLMIServerProperties, AzureArcSQLMIOsWaitstats,\n ## AzureArcSQLMIMemoryClerks, AzureArcSQLMIPerformanceCounters, AzureArcSQLMIRequests, AzureArcSQLMISchedulers") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMIDatabaseIO"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_database_io")) + require.True(t, acc.HasTag("sqlserver_database_io", "sql_instance")) + require.True(t, acc.HasTag("sqlserver_database_io", "database_name")) + require.True(t, acc.HasTag("sqlserver_database_io", "physical_filename")) + require.True(t, acc.HasTag("sqlserver_database_io", "logical_filename")) + require.True(t, acc.HasTag("sqlserver_database_io", "file_type")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "reads")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "read_bytes")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "read_latency_ms")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "write_latency_ms")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "writes")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "write_bytes")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "rg_read_stall_ms")) + require.True(t, acc.HasInt64Field("sqlserver_database_io", "rg_write_stall_ms")) + require.True(t, acc.HasTag("sqlserver_database_io", "replica_updateability")) + + server.Stop() +} + +func TestAzureSQLIntegration_ArcManaged_ServerProperties_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMIServerProperties"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_server_properties")) + require.True(t, acc.HasTag("sqlserver_server_properties", "sql_instance")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "cpu_count")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "server_memory")) + require.True(t, acc.HasTag("sqlserver_server_properties", "sku")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "engine_edition")) + require.True(t, acc.HasTag("sqlserver_server_properties", "hardware_type")) + require.True(t, acc.HasField("sqlserver_server_properties", "uptime")) // Time field. + require.True(t, acc.HasTag("sqlserver_server_properties", "sql_version")) + require.True(t, acc.HasTag("sqlserver_server_properties", "sql_version_desc")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "db_online")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "db_restoring")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "db_recovering")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "db_recoveryPending")) + require.True(t, acc.HasInt64Field("sqlserver_server_properties", "db_suspect")) + require.True(t, acc.HasTag("sqlserver_server_properties", "replica_updateability")) + + // This query should only return one row + require.Equal(t, 1, len(acc.Metrics)) + server.Stop() +} + +func TestAzureSQLIntegration_ArcManaged_OsWaitStats_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMIOsWaitstats"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_waitstats")) + require.True(t, acc.HasTag("sqlserver_waitstats", "sql_instance")) + require.True(t, acc.HasTag("sqlserver_waitstats", "wait_type")) + require.True(t, acc.HasInt64Field("sqlserver_waitstats", "waiting_tasks_count")) + require.True(t, acc.HasInt64Field("sqlserver_waitstats", "wait_time_ms")) + require.True(t, acc.HasInt64Field("sqlserver_waitstats", "max_wait_time_ms")) + require.True(t, acc.HasInt64Field("sqlserver_waitstats", "signal_wait_time_ms")) + require.True(t, acc.HasInt64Field("sqlserver_waitstats", "resource_wait_ms")) + require.True(t, acc.HasTag("sqlserver_waitstats", "wait_category")) + require.True(t, acc.HasTag("sqlserver_waitstats", "replica_updateability")) + + server.Stop() +} + +func TestAzureSQLIntegration_ArcManaged_MemoryClerks_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMIMemoryClerks"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_memory_clerks")) + require.True(t, acc.HasTag("sqlserver_memory_clerks", "sql_instance")) + require.True(t, acc.HasTag("sqlserver_memory_clerks", "clerk_type")) + require.True(t, acc.HasInt64Field("sqlserver_memory_clerks", "size_kb")) + require.True(t, acc.HasTag("sqlserver_memory_clerks", "replica_updateability")) + + server.Stop() +} + +func TestAzureSQLIntegration_ArcManaged_PerformanceCounters_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMIPerformanceCounters"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_performance")) + require.True(t, acc.HasTag("sqlserver_performance", "sql_instance")) + require.True(t, acc.HasTag("sqlserver_performance", "object")) + require.True(t, acc.HasTag("sqlserver_performance", "counter")) + require.True(t, acc.HasTag("sqlserver_performance", "instance")) + require.True(t, acc.HasFloatField("sqlserver_performance", "value")) + require.True(t, acc.HasTag("sqlserver_performance", "counter_type")) + require.True(t, acc.HasTag("sqlserver_performance", "replica_updateability")) + + server.Stop() +} + +func TestAzureSQLIntegration_ArcManaged_Requests_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMIRequests"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_requests")) + require.True(t, acc.HasTag("sqlserver_requests", "sql_instance")) + require.True(t, acc.HasTag("sqlserver_requests", "database_name")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "session_id")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "request_id")) + require.True(t, acc.HasTag("sqlserver_requests", "status")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "cpu_time_ms")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "total_elapsed_time_ms")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "logical_reads")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "writes")) + require.True(t, acc.HasTag("sqlserver_requests", "command")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "wait_time_ms")) + require.True(t, acc.HasTag("sqlserver_requests", "wait_type")) + require.True(t, acc.HasTag("sqlserver_requests", "wait_resource")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "blocking_session_id")) + require.True(t, acc.HasTag("sqlserver_requests", "program_name")) + require.True(t, acc.HasTag("sqlserver_requests", "host_name")) + require.True(t, acc.HasTag("sqlserver_requests", "nt_user_name")) + require.True(t, acc.HasTag("sqlserver_requests", "login_name")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "open_transaction")) + require.True(t, acc.HasTag("sqlserver_requests", "transaction_isolation_level")) + require.True(t, acc.HasInt64Field("sqlserver_requests", "granted_query_memory_pages")) + require.True(t, acc.HasFloatField("sqlserver_requests", "percent_complete")) + require.True(t, acc.HasTag("sqlserver_requests", "statement_text")) + require.True(t, acc.HasField("sqlserver_requests", "objectid")) // Can be null. + require.True(t, acc.HasField("sqlserver_requests", "stmt_object_name")) // Can be null. + require.True(t, acc.HasField("sqlserver_requests", "stmt_db_name")) // Can be null. + require.True(t, acc.HasTag("sqlserver_requests", "query_hash")) + require.True(t, acc.HasTag("sqlserver_requests", "query_plan_hash")) + require.True(t, acc.HasTag("sqlserver_requests", "session_db_name")) + require.True(t, acc.HasTag("sqlserver_requests", "replica_updateability")) + + server.Stop() +} + +func TestAzureSQLIntegration_ArcManaged_Schedulers_Query(t *testing.T) { + if testing.Short() { + t.Skip("Skipping integration test in short mode") + } + + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { + t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") + } + + connectionString := os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") + sl := config.NewSecret([]byte(connectionString)) + + server := &SQLServer{ + Servers: []*config.Secret{&sl}, + IncludeQuery: []string{"AzureArcSQLMISchedulers"}, + AuthMethod: "connection_string", + DatabaseType: "AzureArcSQLManagedInstance", + } + + var acc testutil.Accumulator + + require.NoError(t, server.Start(&acc)) + require.NoError(t, server.Gather(&acc)) + + require.True(t, acc.HasMeasurement("sqlserver_schedulers")) + require.True(t, acc.HasTag("sqlserver_schedulers", "sql_instance")) + require.True(t, acc.HasTag("sqlserver_schedulers", "scheduler_id")) + require.True(t, acc.HasTag("sqlserver_schedulers", "cpu_id")) + require.True(t, acc.HasField("sqlserver_schedulers", "is_online")) // Bool field. + require.True(t, acc.HasField("sqlserver_schedulers", "is_idle")) // Bool field. + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "preemptive_switches_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "context_switches_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "current_tasks_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "runnable_tasks_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "current_workers_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "active_workers_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "work_queue_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "pending_disk_io_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "load_factor")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "yield_count")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "total_cpu_usage_ms")) + require.True(t, acc.HasInt64Field("sqlserver_schedulers", "total_scheduler_delay_ms")) + require.True(t, acc.HasTag("sqlserver_schedulers", "replica_updateability")) + + server.Stop() +} diff --git a/plugins/inputs/sqlserver/sample.conf b/plugins/inputs/sqlserver/sample.conf index 3c5e9d4921e00..8ee99a262d806 100644 --- a/plugins/inputs/sqlserver/sample.conf +++ b/plugins/inputs/sqlserver/sample.conf @@ -48,6 +48,10 @@ ## AzureSQLPoolResourceStats, AzureSQLPoolResourceGovernance, AzureSQLPoolDatabaseIO, AzureSQLPoolWaitStats, ## AzureSQLPoolMemoryClerks, AzureSQLPoolPerformanceCounters, AzureSQLPoolSchedulers + ## Queries enabled by default for database_type = "AzureArcSQLManagedInstance" are - + ## AzureSQLMIDatabaseIO, AzureSQLMIServerProperties, AzureSQLMIOsWaitstats, + ## AzureSQLMIMemoryClerks, AzureSQLMIPerformanceCounters, AzureSQLMIRequests, AzureSQLMISchedulers + ## Following are old config settings ## You may use them only if you are using the earlier flavor of queries, however it is recommended to use ## the new mechanism of identifying the database_type there by use it's corresponding queries diff --git a/plugins/inputs/sqlserver/sqlserver.go b/plugins/inputs/sqlserver/sqlserver.go index 30eb2e737fac5..0d4cfea2ea7ab 100644 --- a/plugins/inputs/sqlserver/sqlserver.go +++ b/plugins/inputs/sqlserver/sqlserver.go @@ -62,10 +62,11 @@ type HealthMetric struct { const defaultServer = "Server=.;app name=telegraf;log=1;" const ( - typeAzureSQLDB = "AzureSQLDB" - typeAzureSQLManagedInstance = "AzureSQLManagedInstance" - typeAzureSQLPool = "AzureSQLPool" - typeSQLServer = "SQLServer" + typeAzureSQLDB = "AzureSQLDB" + typeAzureSQLManagedInstance = "AzureSQLManagedInstance" + typeAzureSQLPool = "AzureSQLPool" + typeSQLServer = "SQLServer" + typeAzureArcSQLManagedInstance = "AzureArcSQLManagedInstance" ) const ( @@ -93,6 +94,7 @@ func (s *SQLServer) initQueries() error { // Constant definitions for type "AzureSQLDB" start with sqlAzureDB // Constant definitions for type "AzureSQLManagedInstance" start with sqlAzureMI // Constant definitions for type "AzureSQLPool" start with sqlAzurePool + // Constant definitions for type "AzureArcSQLManagedInstance" start with sqlAzureArcMI // Constant definitions for type "SQLServer" start with sqlServer if s.DatabaseType == typeAzureSQLDB { queries["AzureSQLDBResourceStats"] = Query{ScriptName: "AzureSQLDBResourceStats", Script: sqlAzureDBResourceStats, ResultByRow: false} @@ -125,6 +127,15 @@ func (s *SQLServer) initQueries() error { queries["AzureSQLPoolPerformanceCounters"] = Query{ScriptName: "AzureSQLPoolPerformanceCounters", Script: sqlAzurePoolPerformanceCounters, ResultByRow: false} queries["AzureSQLPoolSchedulers"] = Query{ScriptName: "AzureSQLPoolSchedulers", Script: sqlAzurePoolSchedulers, ResultByRow: false} + } else if s.DatabaseType == typeAzureArcSQLManagedInstance { + queries["AzureArcSQLMIDatabaseIO"] = Query{ScriptName: "AzureArcSQLMIDatabaseIO", Script: sqlAzureArcMIDatabaseIO, ResultByRow: false} + queries["AzureArcSQLMIServerProperties"] = Query{ScriptName: "AzureArcSQLMIServerProperties", Script: sqlAzureArcMIProperties, ResultByRow: false} + queries["AzureArcSQLMIOsWaitstats"] = Query{ScriptName: "AzureArcSQLMIOsWaitstats", Script: sqlAzureArcMIOsWaitStats, ResultByRow: false} + queries["AzureArcSQLMIMemoryClerks"] = Query{ScriptName: "AzureArcSQLMIMemoryClerks", Script: sqlAzureArcMIMemoryClerks, ResultByRow: false} + queries["AzureArcSQLMIPerformanceCounters"] = + Query{ScriptName: "AzureArcSQLMIPerformanceCounters", Script: sqlAzureArcMIPerformanceCounters, ResultByRow: false} + queries["AzureArcSQLMIRequests"] = Query{ScriptName: "AzureArcSQLMIRequests", Script: sqlAzureArcMIRequests, ResultByRow: false} + queries["AzureArcSQLMISchedulers"] = Query{ScriptName: "AzureArcSQLMISchedulers", Script: sqlAzureArcMISchedulers, ResultByRow: false} } else if s.DatabaseType == typeSQLServer { //These are still V2 queries and have not been refactored yet. queries["SQLServerPerformanceCounters"] = Query{ScriptName: "SQLServerPerformanceCounters", Script: sqlServerPerformanceCounters, ResultByRow: false} queries["SQLServerWaitStatsCategorized"] = Query{ScriptName: "SQLServerWaitStatsCategorized", Script: sqlServerWaitStatsCategorized, ResultByRow: false} From b95e19d0edcfa816f9d8ee77031594ae129cace3 Mon Sep 17 00:00:00 2001 From: Niko Feng Date: Wed, 10 May 2023 10:50:30 +0000 Subject: [PATCH 2/2] feat(inputs.sqlserver): add Azure Arc-enabled SQL MI support --- plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go b/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go index af38f583d6780..5681c10e13b35 100644 --- a/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go +++ b/plugins/inputs/sqlserver/azurearcsqlmiqueries_test.go @@ -14,7 +14,7 @@ func TestAzureSQLIntegration_ArcManaged_DatabaseIO_Query(t *testing.T) { t.Skip("Skipping integration test in short mode") } - if os.Getenv("## Queries enabled by default for database_type = \"AzureArcSQLManagedInstance\" are -\n ## AzureArcSQLMIDatabaseIO, AzureArcSQLMIServerProperties, AzureArcSQLMIOsWaitstats,\n ## AzureArcSQLMIMemoryClerks, AzureArcSQLMIPerformanceCounters, AzureArcSQLMIRequests, AzureArcSQLMISchedulers") == "" { + if os.Getenv("AZURESQL_ARCMI_CONNECTION_STRING") == "" { t.Skip("Missing environment variable AZURESQL_ARCMI_CONNECTION_STRING") }