feat: add additional metrics to support elastic pool (sqlserver plugin) (#9841)

This commit is contained in:
Jean-Sébastien Dupuy 2021-10-26 20:07:02 +02:00 committed by GitHub
parent 7bf8343c60
commit 5d2b5d15a7
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
6 changed files with 1548 additions and 700 deletions

View File

@ -1,18 +1,20 @@
# SQL Server Input Plugin
The `sqlserver` plugin provides metrics for your SQL Server instance. Recorded metrics are
lightweight and use Dynamic Management Views supplied by SQL Server.
### The SQL Server plugin supports the following editions/versions of SQL Server
- SQL Server
- 2012 or newer (Plugin support aligned with the [official Microsoft SQL Server support](https://docs.microsoft.com/en-us/sql/sql-server/end-of-support/sql-server-end-of-life-overview?view=sql-server-ver15#lifecycle-dates))
- End-of-life SQL Server versions are not guaranteed to be supported by Telegraf. Any issues with the SQL Server plugin for these EOL versions will
need to be addressed by the community.
- End-of-life SQL Server versions are not guaranteed to be supported by Telegraf. Any issues with the SQL Server plugin for these EOL versions will need to be addressed by the community.
- Azure SQL Database (Single)
- Azure SQL Managed Instance
### Additional Setup:
### Additional Setup
You have to create a login on every SQL Server instance or Azure SQL Managed instance you want to monitor, with following script:
You have to create a login on every SQL Server instance or Azure SQL Managed instance you want to monitor, with following script:
```sql
USE master;
GO
@ -25,6 +27,7 @@ GO
```
For Azure SQL Database, you require the View Database State permission and can create a user with a password directly in the database.
```sql
CREATE USER [telegraf] WITH PASSWORD = N'mystrongpassword';
GO
@ -32,7 +35,28 @@ GRANT VIEW DATABASE STATE TO [telegraf];
GO
```
### Configuration:
For Azure SQL Elastic Pool, please follow the following instructions to collect metrics.
On master logical database, create an SQL login 'telegraf' and assign it to the server-level role ##MS_ServerStateReader##.
```sql
CREATE LOGIN [telegraf] WITH PASSWORD = N'mystrongpassword';
GO
ALTER SERVER ROLE ##MS_ServerStateReader##
ADD MEMBER [telegraf];
GO
```
Elastic pool metrics can be collected from any database in the pool if a user for the `telegraf` login is created in that database. For collection to work, this database must remain in the pool, and must not be renamed. If you plan to add/remove databases from this pool, create a separate database for monitoring purposes that will remain in the pool.
> Note: To avoid duplicate monitoring data, do not collect elastic pool metrics from more than one database in the same pool.
```sql
GO
CREATE USER [telegraf] FOR LOGIN telegraf;
```
### Configuration
```toml
[agent]
@ -58,42 +82,34 @@ GO
## "database_type" enables a specific set of queries depending on the database type. If specified, it replaces azuredb = true/false and query_version = 2
## In the config file, the sql server plugin section should be repeated each with a set of servers for a specific database_type.
## Possible values for database_type are - "AzureSQLDB" or "AzureSQLManagedInstance" or "SQLServer"
## Possible values for database_type are - "SQLServer" or "AzureSQLDB" or "AzureSQLManagedInstance" or "AzureSQLPool"
database_type = "SQLServer"
## A list of queries to include. If not specified, all the below listed queries are used.
include_query = []
## A list of queries to explicitly ignore.
exclude_query = ["SQLServerAvailabilityReplicaStates", "SQLServerDatabaseReplicaStates"]
## Queries enabled by default for database_type = "SQLServer" are -
## SQLServerPerformanceCounters, SQLServerWaitStatsCategorized, SQLServerDatabaseIO, SQLServerProperties, SQLServerMemoryClerks,
## SQLServerSchedulers, SQLServerRequests, SQLServerVolumeSpace, SQLServerCpu, SQLServerAvailabilityReplicaStates, SQLServerDatabaseReplicaStates
## Queries enabled by default for database_type = "AzureSQLDB" are -
## AzureSQLDBResourceStats, AzureSQLDBResourceGovernance, AzureSQLDBWaitStats, AzureSQLDBDatabaseIO, AzureSQLDBServerProperties,
## AzureSQLDBOsWaitstats, AzureSQLDBMemoryClerks, AzureSQLDBPerformanceCounters, AzureSQLDBRequests, AzureSQLDBSchedulers
# database_type = "AzureSQLDB"
## A list of queries to include. If not specified, all the above listed queries are used.
# include_query = []
## A list of queries to explicitly ignore.
# exclude_query = []
## Queries enabled by default for database_type = "AzureSQLManagedInstance" are -
## AzureSQLMIResourceStats, AzureSQLMIResourceGovernance, AzureSQLMIDatabaseIO, AzureSQLMIServerProperties, AzureSQLMIOsWaitstats,
## AzureSQLMIMemoryClerks, AzureSQLMIPerformanceCounters, AzureSQLMIRequests, AzureSQLMISchedulers
# database_type = "AzureSQLManagedInstance"
## Queries enabled by default for database_type = "AzureSQLPool" are -
## AzureSQLPoolResourceStats, AzureSQLPoolResourceGovernance, AzureSQLPoolDatabaseIO, AzureSQLPoolWaitStats,
## AzureSQLPoolMemoryClerks, AzureSQLPoolPerformanceCounters, AzureSQLPoolSchedulers
# include_query = []
# exclude_query = []
## Queries enabled by default for database_type = "SQLServer" are -
## SQLServerPerformanceCounters, SQLServerWaitStatsCategorized, SQLServerDatabaseIO, SQLServerProperties, SQLServerMemoryClerks,
## SQLServerSchedulers, SQLServerRequests, SQLServerVolumeSpace, SQLServerCpu
database_type = "SQLServer"
include_query = []
## SQLServerAvailabilityReplicaStates and SQLServerDatabaseReplicaStates are optional queries and hence excluded here as default
exclude_query = ["SQLServerAvailabilityReplicaStates", "SQLServerDatabaseReplicaStates"]
## 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
## 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
## Optional parameter, setting this to 2 will use a new version
@ -126,30 +142,39 @@ GO
## - AzureSQLDBRequests
## - AzureSQLDBSchedulers
## database_type = AzureSQLManagedInstance by default collects the following queries
## - AzureSQLMIResourceStats
## - AzureSQLMIResourceGovernance
## - AzureSQLMIDatabaseIO
## - AzureSQLMIServerProperties
## - AzureSQLMIOsWaitstats
## - AzureSQLMIMemoryClerks
## - AzureSQLMIPerformanceCounters
## - AzureSQLMIRequests
## - AzureSQLMISchedulers
## database_type = AzureSQLManagedInstance by default collects the following queries
## - AzureSQLMIResourceStats
## - AzureSQLMIResourceGovernance
## - AzureSQLMIDatabaseIO
## - AzureSQLMIServerProperties
## - AzureSQLMIOsWaitstats
## - AzureSQLMIMemoryClerks
## - AzureSQLMIPerformanceCounters
## - AzureSQLMIRequests
## - AzureSQLMISchedulers
## database_type = SQLServer by default collects the following queries
## - SQLServerPerformanceCounters
## - SQLServerWaitStatsCategorized
## - SQLServerDatabaseIO
## - SQLServerProperties
## - SQLServerMemoryClerks
## - SQLServerSchedulers
## - SQLServerRequests
## - SQLServerVolumeSpace
## - SQLServerCpu
## and following as optional (if mentioned in the include_query list)
## - SQLServerAvailabilityReplicaStates
## - SQLServerDatabaseReplicaStates
## database_type = AzureSQLPool by default collects the following queries
## - AzureSQLPoolResourceStats
## - AzureSQLPoolResourceGovernance
## - AzureSQLPoolDatabaseIO
## - AzureSQLPoolOsWaitStats,
## - AzureSQLPoolMemoryClerks
## - AzureSQLPoolPerformanceCounters
## - AzureSQLPoolSchedulers
## database_type = SQLServer by default collects the following queries
## - SQLServerPerformanceCounters
## - SQLServerWaitStatsCategorized
## - SQLServerDatabaseIO
## - SQLServerProperties
## - SQLServerMemoryClerks
## - SQLServerSchedulers
## - SQLServerRequests
## - SQLServerVolumeSpace
## - SQLServerCpu
## and following as optional (if mentioned in the include_query list)
## - SQLServerAvailabilityReplicaStates
## - SQLServerDatabaseReplicaStates
## Version 2 by default collects the following queries
## Version 2 is being deprecated, please consider using database_type.
@ -175,7 +200,6 @@ GO
## - MemoryClerk
## - VolumeSpace
## - PerformanceMetrics
```
### Support for Azure Active Directory (AAD) authentication using [Managed Identity](https://docs.microsoft.com/en-us/azure/active-directory/managed-identities-azure-resources/overview)
@ -190,6 +214,7 @@ To enable support for AAD authentication, we leverage the existing AAD authentic
- Configure "system-assigned managed identity" for Azure resources on the Monitoring VM (the VM that'd connect to the SQL server/database) [using the Azure portal](https://docs.microsoft.com/en-us/azure/active-directory/managed-identities-azure-resources/qs-configure-portal-windows-vm).
- On the database being monitored, create/update a USER with the name of the Monitoring VM as the principal using the below script. This might require allow-listing the client machine's IP address (from where the below SQL script is being run) on the SQL Server resource.
```sql
EXECUTE ('IF EXISTS(SELECT * FROM sys.database_principals WHERE name = ''<Monitoring_VM_Name>'')
BEGIN
@ -198,25 +223,31 @@ EXECUTE ('IF EXISTS(SELECT * FROM sys.database_principals WHERE name = ''<Monito
EXECUTE ('CREATE USER [<Monitoring_VM_Name>] FROM EXTERNAL PROVIDER')
EXECUTE ('GRANT VIEW DATABASE STATE TO [<Monitoring_VM_Name>]')
```
- On the SQL Server resource of the database(s) being monitored, go to "Firewalls and Virtual Networks" tab and allowlist the monitoring VM IP address.
- On the Monitoring VM, update the telegraf config file with the database connection string in the following format. Please note AAD based auth is currently only supported for Azure SQL Database and Azure SQL Managed Instance (but not for SQL Server), as described [here](https://docs.microsoft.com/en-us/azure/azure-sql/database/security-overview#authentication).
- On the Monitoring VM, update the telegraf config file with the database connection string in the following format.
- On the Monitoring VM, update the telegraf config file with the database connection string in the following format. The connection string only provides the server and database name, but no password (since the VM's system-assigned managed identity would be used for authentication). The auth method must be set to "AAD"
```toml
servers = [
"Server=<Azure_SQL_Server_Name>.database.windows.net;Port=1433;Database=<Azure_SQL_Database_Name>;app name=telegraf;log=1;",
]
auth_method = "AAD"
```
- Please note AAD based auth is currently only supported for Azure SQL Database and Azure SQL Managed Instance (but not for SQL Server), as described [here](https://docs.microsoft.com/en-us/azure/azure-sql/database/security-overview#authentication).
### Metrics:
### Metrics
To provide backwards compatibility, this plugin support two versions of metrics queries.
**Note**: Version 2 queries are not backwards compatible with the old queries. Any dashboards or queries based on the old query format will not work with the new format. The version 2 queries only report raw metrics, no math has been done to calculate deltas. To graph this data you must calculate deltas in your dashboarding software.
#### Version 1 (query_version=1): This is Deprecated in 1.6, all future development will be under configuration option database_type.
#### Version 1 (query_version=1): This is Deprecated in 1.6, all future development will be under configuration option database_type
The original metrics queries provide:
- *Performance counters*: 1000+ metrics from `sys.dm_os_performance_counters`
- *Performance metrics*: special performance and ratio metrics
- *Wait stats*: wait tasks categorized from `sys.dm_os_wait_stats`
@ -229,12 +260,15 @@ The original metrics queries provide:
- *CPU*: cpu usage from `sys.dm_os_ring_buffers`
If you are using the original queries all stats have the following tags:
- `servername`: hostname:instance
- `type`: type of stats to easily filter measurements
#### Version 2 (query_version=2): Being deprecated, All future development will be under configuration option database_type.
#### Version 2 (query_version=2): Being deprecated, All future development will be under configuration option database_type
The new (version 2) metrics provide:
- *Database IO*: IO stats from `sys.dm_io_virtual_file_stats`
- *Database IO*: IO stats from `sys.dm_io_virtual_file_stats`.
- *Memory Clerk*: Memory clerk breakdown from `sys.dm_os_memory_clerks`, most clerks have been given a friendly name.
- *Performance Counters*: A select list of performance counters from `sys.dm_os_performance_counters`. Some of the important metrics included:
- *Activity*: Transactions/sec/database, Batch requests/sec, blocked processes, + more
@ -263,115 +297,133 @@ The new (version 2) metrics provide:
- Stats from `sys.dm_db_wait_stats`
- Resource governance stats from `sys.dm_user_db_resource_governance`
- Stats from `sys.dm_db_resource_stats`
#### database_type = "AzureSQLDB"
#### database_type = "AzureSQLDB
These are metrics for Azure SQL Database (single database) and are very similar to version 2 but split out for maintenance reasons, better ability to test,differences in DMVs:
- AzureSQLDBDatabaseIO: IO stats from `sys.dm_io_virtual_file_stats` including resource governance time, RBPEX, IO for Hyperscale.
- AzureSQLDBMemoryClerks: Memory clerk breakdown from `sys.dm_os_memory_clerks`.
= AzureSQLDBResourceGovernance: Relevant properties indicatign resource limits from `sys.dm_user_db_resource_governance`
- AzureSQLDBPerformanceCounters: A select list of performance counters from `sys.dm_os_performance_counters` including cloud specific counters for SQL Hyperscale.
- AzureSQLDBServerProperties: Relevant Azure SQL relevant properties from such as Tier, #Vcores, Memory etc, storage, etc.
- AzureSQLDBWaitstats: Wait time in ms from `sys.dm_db_wait_stats`, 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. These waits are collected only as of the end of the a statement. and for a specific database only.
- *AzureSQLDBDatabaseIO*: IO stats from `sys.dm_io_virtual_file_stats` including resource governance time, RBPEX, IO for Hyperscale.
- *AzureSQLDBMemoryClerks*: Memory clerk breakdown from `sys.dm_os_memory_clerks`.
- *AzureSQLDBResourceGovernance*: Relevant properties indicatign resource limits from `sys.dm_user_db_resource_governance`
- *AzureSQLDBPerformanceCounters*: A select list of performance counters from `sys.dm_os_performance_counters` including cloud specific counters for SQL Hyperscale.
- *AzureSQLDBServerProperties*: Relevant Azure SQL relevant properties from such as Tier, #Vcores, Memory etc, storage, etc.
- *AzureSQLDBWaitstats*: Wait time in ms from `sys.dm_db_wait_stats`, 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. These waits are collected only as of the end of the a statement. and for a specific database only.
- *AzureSQLOsWaitstats*: Wait time in ms from `sys.dm_os_wait_stats`, 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. These waits are collected as they occur and instance wide
- *AzureSQLDBRequests: Requests which are blocked or have a wait type from `sys.dm_exec_sessions` and `sys.dm_exec_requests`
- *AzureSQLDBSchedulers* - This captures `sys.dm_os_schedulers` snapshots.
#### database_type = "AzureSQLManagedInstance"
#### database_type = "AzureSQLManagedInstance
These are metrics for Azure SQL Managed instance, are very similar to version 2 but split out for maintenance reasons, better ability to test, differences in DMVs:
- AzureSQLMIDatabaseIO: IO stats from `sys.dm_io_virtual_file_stats` including resource governance time, RBPEX, IO for Hyperscale.
- AzureSQLMIMemoryClerks: Memory clerk breakdown from `sys.dm_os_memory_clerks`.
- AzureSQLMIResourceGovernance: Relevant properties indicatign resource limits from `sys.dm_instance_resource_governance`
- AzureSQLMIPerformanceCounters: A select list of performance counters from `sys.dm_os_performance_counters` including cloud specific counters for SQL Hyperscale.
- AzureSQLMIServerProperties: Relevant Azure SQL relevant properties such as Tier, #Vcores, Memory etc, storage, etc.
- AzureSQLMIOsWaitstats: Wait time in ms from `sys.dm_os_wait_stats`, 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. These waits are collected as they occur and instance wide
- AzureSQLMIRequests: Requests which are blocked or have a wait type from `sys.dm_exec_sessions` and `sys.dm_exec_requests`
- AzureSQLMISchedulers - This captures `sys.dm_os_schedulers` snapshots.
#### database_type = "SQLServer
- SQLServerDatabaseIO: IO stats from `sys.dm_io_virtual_file_stats`
- SQLServerMemoryClerks: Memory clerk breakdown from `sys.dm_os_memory_clerks`, most clerks have been given a friendly name.
- SQLServerPerformanceCounters: A select list of performance counters from `sys.dm_os_performance_counters`. Some of the important metrics included:
- *AzureSQLMIDatabaseIO*: IO stats from `sys.dm_io_virtual_file_stats` including resource governance time, RBPEX, IO for Hyperscale.
- *AzureSQLMIMemoryClerks*: Memory clerk breakdown from `sys.dm_os_memory_clerks`.
- *AzureSQLMIResourceGovernance*: Relevant properties indicatign resource limits from `sys.dm_instance_resource_governance`
- *AzureSQLMIPerformanceCounters*: A select list of performance counters from `sys.dm_os_performance_counters` including cloud specific counters for SQL Hyperscale.
- *AzureSQLMIServerProperties*: Relevant Azure SQL relevant properties such as Tier, #Vcores, Memory etc, storage, etc.
- *AzureSQLMIOsWaitstats*: Wait time in ms from `sys.dm_os_wait_stats`, 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. These waits are collected as they occur and instance wide
- *AzureSQLMIRequests*: Requests which are blocked or have a wait type from `sys.dm_exec_sessions` and `sys.dm_exec_requests`
- *AzureSQLMISchedulers*: This captures `sys.dm_os_schedulers` snapshots.
#### database_type = "AzureSQLPool"
These are metrics for Azure SQL to monitor resources usage at Elastic Pool level. These metrics require additional permissions to be collected, please ensure to check additional setup section in this documentation.
- *AzureSQLPoolResourceStats*: Returns resource usage statistics for the current elastic pool in a SQL Database server. Queried from `sys.dm_resource_governor_resource_pools_history_ex`.
- *AzureSQLPoolResourceGovernance*: Returns actual configuration and capacity settings used by resource governance mechanisms in the current elastic pool. Queried from `sys.dm_user_db_resource_governance`.
- *AzureSQLPoolDatabaseIO*: Returns I/O statistics for data and log files for each database in the pool. Queried from `sys.dm_io_virtual_file_stats`.
- *AzureSQLPoolOsWaitStats*: Returns information about all the waits encountered by threads that executed. Queried from `sys.dm_os_wait_stats`.
- *AzureSQLPoolMemoryClerks*: Memory clerk breakdown from `sys.dm_os_memory_clerks`.
- *AzureSQLPoolPerformanceCounters*: A selected list of performance counters from `sys.dm_os_performance_counters`. Note: Performance counters where the cntr_type column value is 537003264 are already returned with a percentage format between 0 and 100. For other counters, please check [sys.dm_os_performance_counters](https://docs.microsoft.com/en-us/sql/relational-databases/system-dynamic-management-views/sys-dm-os-performance-counters-transact-sql?view=azuresqldb-current) documentation.
- *AzureSQLPoolSchedulers*: This captures `sys.dm_os_schedulers` snapshots.
#### database_type = "SQLServer"
- *SQLServerDatabaseIO*: IO stats from `sys.dm_io_virtual_file_stats`
- *SQLServerMemoryClerks*: Memory clerk breakdown from `sys.dm_os_memory_clerks`, most clerks have been given a friendly name.
- *SQLServerPerformanceCounters*: A select list of performance counters from `sys.dm_os_performance_counters`. Some of the important metrics included:
- *Activity*: Transactions/sec/database, Batch requests/sec, blocked processes, + more
- *Availability Groups*: Bytes sent to replica, Bytes received from replica, Log bytes received, Log send queue, transaction delay, + more
- *Log activity*: Log bytes flushed/sec, Log flushes/sec, Log Flush Wait Time
- *Memory*: PLE, Page reads/sec, Page writes/sec, + more
- *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
- SQLServerProperties: Number of databases in all possible states (online, offline, suspect, etc.), cpu count, physical memory, SQL Server service uptime, and SQL Server version. In the case of Azure SQL relevant properties such as Tier, #Vcores, Memory etc.
- SQLServerWaitStatsCategorized: 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.
- SQLServerSchedulers - This captures `sys.dm_os_schedulers`.
- SQLServerRequests - This captures a snapshot of `sys.dm_exec_requests` and `sys.dm_exec_sessions` that gives you running requests as well as wait types and
- *SQLServerProperties*: Number of databases in all possible states (online, offline, suspect, etc.), cpu count, physical memory, SQL Server service uptime, and SQL Server version. In the case of Azure SQL relevant properties such as Tier, #Vcores, Memory etc.
- *SQLServerWaitStatsCategorized*: 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.
- *SQLServerSchedulers*: This captures `sys.dm_os_schedulers`.
- *SQLServerRequests*: This captures a snapshot of `sys.dm_exec_requests` and `sys.dm_exec_sessions` that gives you running requests as well as wait types and
blocking sessions.
- SQLServerVolumeSpace - uses `sys.dm_os_volume_stats` to get total, used and occupied space on every disk that contains a data or log file. (Note that even if enabled it won't get any data from Azure SQL Database or SQL Managed Instance). It is pointless to run this with high frequency (ie: every 10s), but it won't cause any problem.
- SQLServerCpu - uses the buffer ring (`sys.dm_os_ring_buffers`) to get CPU data, the table is updated once per minute. (Note that even if enabled it won't get any data from Azure SQL Database or SQL Managed Instance).
- *SQLServerVolumeSpace*: Uses `sys.dm_os_volume_stats` to get total, used and occupied space on every disk that contains a data or log file. (Note that even if enabled it won't get any data from Azure SQL Database or SQL Managed Instance). It is pointless to run this with high frequency (ie: every 10s), but it won't cause any problem.
- SQLServerCpu: Uses the buffer ring (`sys.dm_os_ring_buffers`) to get CPU data, the table is updated once per minute. (Note that even if enabled it won't get any data from Azure SQL Database or SQL Managed Instance).
- SQLServerAvailabilityReplicaStates: Collects availability replica state information from `sys.dm_hadr_availability_replica_states` for a High Availability / Disaster Recovery (HADR) setup
- SQLServerDatabaseReplicaStates: Collects database replica state information from `sys.dm_hadr_database_replica_states` for a High Availability / Disaster Recovery (HADR) setup
#### Output Measures
The guiding principal is that all data collected from the same primary DMV ends up in the same measure irrespective of database_type.
`sqlserver_database_io` - Used by AzureSQLDBDatabaseIO, AzureSQLMIDatabaseIO, SQLServerDatabaseIO, DatabaseIO given the data is from `sys.dm_io_virtual_file_stats`
`sqlserver_waitstats` - Used by WaitStatsCategorized,AzureSQLDBOsWaitstats,AzureSQLMIOsWaitstats
`sqlserver_server_properties` - Used by SQLServerProperties, AzureSQLDBServerProperties , AzureSQLMIServerProperties,ServerProperties
`sqlserver_memory_clerks` - Used by SQLServerMemoryClerks, AzureSQLDBMemoryClerks, AzureSQLMIMemoryClerks,MemoryClerk
`sqlserver_performance` - Used by SQLServerPerformanceCounters, AzureSQLDBPerformanceCounters, AzureSQLMIPerformanceCounters,PerformanceCounters
`sys.dm_os_schedulers` - Used by SQLServerSchedulers,AzureSQLDBServerSchedulers, AzureSQLMIServerSchedulers
- `sqlserver_database_io` - Used by AzureSQLDBDatabaseIO, AzureSQLMIDatabaseIO, SQLServerDatabaseIO, DatabaseIO given the data is from `sys.dm_io_virtual_file_stats`
- `sqlserver_waitstats` - Used by WaitStatsCategorized,AzureSQLDBOsWaitstats,AzureSQLMIOsWaitstats
- `sqlserver_server_properties` - Used by SQLServerProperties, AzureSQLDBServerProperties , AzureSQLMIServerProperties,ServerProperties
- `sqlserver_memory_clerks` - Used by SQLServerMemoryClerks, AzureSQLDBMemoryClerks, AzureSQLMIMemoryClerks,MemoryClerk
- `sqlserver_performance` - Used by SQLServerPerformanceCounters, AzureSQLDBPerformanceCounters, AzureSQLMIPerformanceCounters,PerformanceCounters
- `sys.dm_os_schedulers` - Used by SQLServerSchedulers,AzureSQLDBServerSchedulers, AzureSQLMIServerSchedulers
The following Performance counter metrics can be used directly, with no delta calculations:
- SQLServer:Buffer Manager\Buffer cache hit ratio
- SQLServer:Buffer Manager\Page life expectancy
- SQLServer:Buffer Node\Page life expectancy
- SQLServer:Database Replica\Log Apply Pending Queue
- SQLServer:Database Replica\Log Apply Ready Queue
- SQLServer:Database Replica\Log Send Queue
- SQLServer:Database Replica\Recovery Queue
- SQLServer:Databases\Data File(s) Size (KB)
- SQLServer:Databases\Log File(s) Size (KB)
- SQLServer:Databases\Log File(s) Used Size (KB)
- SQLServer:Databases\XTP Memory Used (KB)
- SQLServer:General Statistics\Active Temp Tables
- SQLServer:General Statistics\Processes blocked
- SQLServer:General Statistics\Temp Tables For Destruction
- SQLServer:General Statistics\User Connections
- SQLServer:Memory Broker Clerks\Memory broker clerk size
- SQLServer:Memory Manager\Memory Grants Pending
- SQLServer:Memory Manager\Target Server Memory (KB)
- SQLServer:Memory Manager\Total Server Memory (KB)
- SQLServer:Resource Pool Stats\Active memory grant amount (KB)
- SQLServer:Resource Pool Stats\Disk Read Bytes/sec
- SQLServer:Resource Pool Stats\Disk Read IO Throttled/sec
- SQLServer:Resource Pool Stats\Disk Read IO/sec
- SQLServer:Resource Pool Stats\Disk Write Bytes/sec
- SQLServer:Resource Pool Stats\Disk Write IO Throttled/sec
- SQLServer:Resource Pool Stats\Disk Write IO/sec
- SQLServer:Resource Pool Stats\Used memory (KB)
- SQLServer:Transactions\Free Space in tempdb (KB)
- SQLServer:Transactions\Version Store Size (KB)
- SQLServer:User Settable\Query
- SQLServer:Workload Group Stats\Blocked tasks
- SQLServer:Workload Group Stats\CPU usage %
- SQLServer:Workload Group Stats\Queued requests
- SQLServer:Workload Group Stats\Requests completed/sec
- SQLServer:Buffer Manager\Buffer cache hit ratio
- SQLServer:Buffer Manager\Page life expectancy
- SQLServer:Buffer Node\Page life expectancy
- SQLServer:Database Replica\Log Apply Pending Queue
- SQLServer:Database Replica\Log Apply Ready Queue
- SQLServer:Database Replica\Log Send Queue
- SQLServer:Database Replica\Recovery Queue
- SQLServer:Databases\Data File(s) Size (KB)
- SQLServer:Databases\Log File(s) Size (KB)
- SQLServer:Databases\Log File(s) Used Size (KB)
- SQLServer:Databases\XTP Memory Used (KB)
- SQLServer:General Statistics\Active Temp Tables
- SQLServer:General Statistics\Processes blocked
- SQLServer:General Statistics\Temp Tables For Destruction
- SQLServer:General Statistics\User Connections
- SQLServer:Memory Broker Clerks\Memory broker clerk size
- SQLServer:Memory Manager\Memory Grants Pending
- SQLServer:Memory Manager\Target Server Memory (KB)
- SQLServer:Memory Manager\Total Server Memory (KB)
- SQLServer:Resource Pool Stats\Active memory grant amount (KB)
- SQLServer:Resource Pool Stats\Disk Read Bytes/sec
- SQLServer:Resource Pool Stats\Disk Read IO Throttled/sec
- SQLServer:Resource Pool Stats\Disk Read IO/sec
- SQLServer:Resource Pool Stats\Disk Write Bytes/sec
- SQLServer:Resource Pool Stats\Disk Write IO Throttled/sec
- SQLServer:Resource Pool Stats\Disk Write IO/sec
- SQLServer:Resource Pool Stats\Used memory (KB)
- SQLServer:Transactions\Free Space in tempdb (KB)
- SQLServer:Transactions\Version Store Size (KB)
- SQLServer:User Settable\Query
- SQLServer:Workload Group Stats\Blocked tasks
- SQLServer:Workload Group Stats\CPU usage %
- SQLServer:Workload Group Stats\Queued requests
- SQLServer:Workload Group Stats\Requests completed/sec
Version 2 queries have the following tags:
- `sql_instance`: Physical host and instance name (hostname:instance)
- `database_name`: For Azure SQLDB, database_name denotes the name of the Azure SQL Database as server name is a logical construct.
#### Health Metric
All collection versions (version 1, version 2, and database_type) support an optional plugin health metric called `sqlserver_telegraf_health`. This metric tracks if connections to SQL Server are succeeding or failing. Users can leverage this metric to detect if their SQL Server monitoring is not working as intended.
In the configuration file, toggling `health_metric` to `true` will enable collection of this metric. By default, this value is set to `false` and the metric is not collected. The health metric emits one record for each connection specified by `servers` in the configuration file.
The health metric emits the following tags:
- `sql_instance` - Name of the server specified in the connection string. This value is emitted as-is in the connection string. If the server could not be parsed from the connection string, a constant placeholder value is emitted
- `database_name` - Name of the database or (initial catalog) specified in the connection string. This value is emitted as-is in the connection string. If the database could not be parsed from the connection string, a constant placeholder value is emitted
The health metric emits the following fields:
- `attempted_queries` - Number of queries that were attempted for this connection
- `successful_queries` - Number of queries that completed successfully for this connection
- `database_type` - Type of database as specified by `database_type`. If `database_type` is empty, the `QueryVersion` and `AzureDB` fields are concatenated instead

View File

@ -5,7 +5,7 @@ import (
)
//------------------------------------------------------------------------------------------------
//------------------ Azure SQL Database ------------------------------------------------------
//------------------ Azure SQL Database ----------------------------------------------------------
//------------------------------------------------------------------------------------------------
// Only executed if AzureDB flag is set
const sqlAzureDBResourceStats string = `
@ -38,7 +38,7 @@ ORDER BY
[end_time] DESC;
`
// Resource Governamce is only relevant to Azure SQL DB into separate collector
// Resource Governance is only relevant to Azure SQL DB into separate collector
// This will only be collected for Azure SQL Database.
const sqlAzureDBResourceGovernance string = `
IF SERVERPROPERTY('EngineEdition') <> 5 BEGIN /*not Azure SQL DB*/
@ -678,544 +678,3 @@ SELECT
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM sys.dm_os_schedulers AS s
`
//------------------------------------------------------------------------------------------------
//------------------ Azure Managed Instance ------------------------------------------------------
//------------------------------------------------------------------------------------------------
const sqlAzureMIProperties = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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]
,[virtual_core_count] AS [cpu_count]
,(SELECT [process_memory_limit_mb] FROM sys.dm_os_job_object) AS [server_memory]
,[sku]
,SERVERPROPERTY('EngineEdition') AS [engine_edition]
,[hardware_generation] AS [hardware_type]
,cast([reserved_storage_mb] as bigint) AS [total_storage_mb]
,cast(([reserved_storage_mb] - [storage_space_used_mb]) as bigint) AS [available_storage_mb]
,(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]
,[db_online]
,[db_restoring]
,[db_recovering]
,[db_recoveryPending]
,[db_suspect]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM sys.server_resource_stats
CROSS APPLY (
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] IN (6,10) THEN 1 ELSE 0 END ) AS [db_offline]
FROM sys.databases
) AS dbs
ORDER BY
[start_time] DESC;
`
const sqlAzureMIResourceStats = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT TOP(1)
'sqlserver_azure_db_resource_stats' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,cast([avg_cpu_percent] as float) as [avg_cpu_percent]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM
sys.server_resource_stats
ORDER BY
[end_time] DESC;
`
const sqlAzureMIResourceGovernance string = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT
'sqlserver_instance_resource_governance' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,[instance_cap_cpu]
,[instance_max_log_rate]
,[instance_max_worker_threads]
,[tempdb_log_file_number]
,[volume_local_iops]
,[volume_external_xstore_iops]
,[volume_managed_xstore_iops]
,[volume_type_local_iops] as [voltype_local_iops]
,[volume_type_managed_xstore_iops] as [voltype_man_xtore_iops]
,[volume_type_external_xstore_iops] as [voltype_ext_xtore_iops]
,[volume_external_xstore_iops] as [vol_ext_xtore_iops]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM sys.dm_instance_resource_governance;
`
const sqlAzureMIDatabaseIO = `
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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]
,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 sqlAzureMIMemoryClerks = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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 sqlAzureMIOsWaitStats = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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 sqlAzureMIPerformanceCounters = `
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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 sqlAzureMIRequests string = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT [blocking_session_id] INTO #blockingSessions FROM sys.dm_exec_requests WHERE [blocking_session_id] != 0
CREATE INDEX ix_blockingSessions_1 on #blockingSessions ([blocking_session_id])
SELECT
'sqlserver_requests' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,DB_NAME() as [database_name]
,s.[session_id]
,ISNULL(r.[request_id], 0) as [request_id]
,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]
,r.[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]) [stmt_db_name]
,CONVERT(varchar(20),[query_hash],1) as [query_hash]
,CONVERT(varchar(20),[query_plan_hash],1) as [query_plan_hash]
,DB_NAME(COALESCE(r.[database_id], s.[database_id])) AS [session_db_name]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
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
WHERE
(s.session_id IN (SELECT blocking_session_id FROM #blockingSessions))
OR (
r.session_id IS NOT NULL
AND (
s.is_user_process = 1
OR r.status COLLATE Latin1_General_BIN NOT IN ('background', 'sleeping')
)
)
OPTION(MAXDOP 1);
`
const sqlAzureMISchedulers string = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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
`

View File

@ -0,0 +1,546 @@
package sqlserver
import (
_ "github.com/denisenkom/go-mssqldb" // go-mssqldb initialization
)
//------------------------------------------------------------------------------------------------
//------------------ Azure Managed Instance ------------------------------------------------------
//------------------------------------------------------------------------------------------------
const sqlAzureMIProperties = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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]
,[virtual_core_count] AS [cpu_count]
,(SELECT [process_memory_limit_mb] FROM sys.dm_os_job_object) AS [server_memory]
,[sku]
,SERVERPROPERTY('EngineEdition') AS [engine_edition]
,[hardware_generation] AS [hardware_type]
,cast([reserved_storage_mb] as bigint) AS [total_storage_mb]
,cast(([reserved_storage_mb] - [storage_space_used_mb]) as bigint) AS [available_storage_mb]
,(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]
,[db_online]
,[db_restoring]
,[db_recovering]
,[db_recoveryPending]
,[db_suspect]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM sys.server_resource_stats
CROSS APPLY (
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] IN (6,10) THEN 1 ELSE 0 END ) AS [db_offline]
FROM sys.databases
) AS dbs
ORDER BY
[start_time] DESC;
`
const sqlAzureMIResourceStats = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT TOP(1)
'sqlserver_azure_db_resource_stats' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,cast([avg_cpu_percent] as float) as [avg_cpu_percent]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM
sys.server_resource_stats
ORDER BY
[end_time] DESC;
`
const sqlAzureMIResourceGovernance string = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT
'sqlserver_instance_resource_governance' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,[instance_cap_cpu]
,[instance_max_log_rate]
,[instance_max_worker_threads]
,[tempdb_log_file_number]
,[volume_local_iops]
,[volume_external_xstore_iops]
,[volume_managed_xstore_iops]
,[volume_type_local_iops] as [voltype_local_iops]
,[volume_type_managed_xstore_iops] as [voltype_man_xtore_iops]
,[volume_type_external_xstore_iops] as [voltype_ext_xtore_iops]
,[volume_external_xstore_iops] as [vol_ext_xtore_iops]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
FROM sys.dm_instance_resource_governance;
`
const sqlAzureMIDatabaseIO = `
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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]
,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 sqlAzureMIMemoryClerks = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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 sqlAzureMIOsWaitStats = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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 sqlAzureMIPerformanceCounters = `
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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 sqlAzureMIRequests string = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT [blocking_session_id] INTO #blockingSessions FROM sys.dm_exec_requests WHERE [blocking_session_id] != 0
CREATE INDEX ix_blockingSessions_1 on #blockingSessions ([blocking_session_id])
SELECT
'sqlserver_requests' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,DB_NAME() as [database_name]
,s.[session_id]
,ISNULL(r.[request_id], 0) as [request_id]
,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]
,r.[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]) [stmt_db_name]
,CONVERT(varchar(20),[query_hash],1) as [query_hash]
,CONVERT(varchar(20),[query_plan_hash],1) as [query_plan_hash]
,DB_NAME(COALESCE(r.[database_id], s.[database_id])) AS [session_db_name]
,DATABASEPROPERTYEX(DB_NAME(), 'Updateability') as replica_updateability
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
WHERE
(s.session_id IN (SELECT blocking_session_id FROM #blockingSessions))
OR (
r.session_id IS NOT NULL
AND (
s.is_user_process = 1
OR r.status COLLATE Latin1_General_BIN NOT IN ('background', 'sleeping')
)
)
OPTION(MAXDOP 1);
`
const sqlAzureMISchedulers string = `
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure 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
`

View File

@ -0,0 +1,477 @@
package sqlserver
import (
_ "github.com/denisenkom/go-mssqldb" // go-mssqldb initialization
)
//------------------------------------------------------------------------------------------------
//------------------ Azure Sql Elastic Pool ------------------------------------------------------
//------------------------------------------------------------------------------------------------
const sqlAzurePoolResourceStats = `
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT TOP(1)
'sqlserver_pool_resource_stats' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,(SELECT [elastic_pool_name] FROM sys.database_service_objectives WHERE database_id = DB_ID()) AS [elastic_pool_name]
,[snapshot_time]
,cast([cap_vcores_used_percent] as float) AS [avg_cpu_percent]
,cast([avg_data_io_percent] as float) AS [avg_data_io_percent]
,cast([avg_log_write_percent] as float) AS [avg_log_write_percent]
,cast([avg_storage_percent] as float) AS [avg_storage_percent]
,cast([max_worker_percent] as float) AS [max_worker_percent]
,cast([max_session_percent] as float) AS [max_session_percent]
,cast([max_data_space_kb]/1024. as int) AS [storage_limit_mb]
,cast([avg_instance_cpu_percent] as float) AS [avg_instance_cpu_percent]
,cast([avg_allocated_storage_percent] as float) AS [avg_allocated_storage_percent]
FROM
sys.dm_resource_governor_resource_pools_history_ex
WHERE
[name] = 'SloSharedPool1'
ORDER BY
[snapshot_time] DESC;
`
const sqlAzurePoolResourceGovernance = `
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT
'sqlserver_pool_resource_governance' AS [measurement]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,(SELECT [elastic_pool_name] FROM sys.database_service_objectives WHERE database_id = DB_ID()) AS [elastic_pool_name]
,[slo_name]
,[dtu_limit]
,[cpu_limit]
,[max_cpu]
,[cap_cpu]
,[max_db_memory]
,[max_db_max_size_in_mb]
,[db_file_growth_in_mb]
,[log_size_in_mb]
,[instance_cap_cpu]
,[instance_max_log_rate]
,[instance_max_worker_threads]
,[checkpoint_rate_mbps]
,[checkpoint_rate_io]
,[primary_group_max_workers]
,[primary_min_log_rate]
,[primary_max_log_rate]
,[primary_group_min_io]
,[primary_group_max_io]
,[primary_group_min_cpu]
,[primary_group_max_cpu]
,[primary_pool_max_workers]
,[pool_max_io]
,[volume_local_iops]
,[volume_managed_xstore_iops]
,[volume_external_xstore_iops]
,[volume_type_local_iops]
,[volume_type_managed_xstore_iops]
,[volume_type_external_xstore_iops]
,[volume_pfs_iops]
,[volume_type_pfs_iops]
FROM
sys.dm_user_db_resource_governance
WHERE database_id = DB_ID();
`
const sqlAzurePoolDatabaseIO = `
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. 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]
,(SELECT [elastic_pool_name] FROM sys.database_service_objectives WHERE database_id = DB_ID()) AS [elastic_pool_name]
,CASE
WHEN vfs.[database_id] = 1 THEN 'master'
WHEN vfs.[database_id] = 2 THEN 'tempdb'
WHEN vfs.[database_id] = 3 THEN 'model'
WHEN vfs.[database_id] = 4 THEN 'msdb'
ELSE gov.[database_name]
END AS [database_name]
,vfs.[database_id]
,vfs.[file_id]
,CASE
WHEN vfs.[file_id] = 2 THEN 'LOG'
ELSE 'ROWS'
END AS [file_type]
,vfs.[num_of_reads] AS [reads]
,vfs.[num_of_bytes_read] AS [read_bytes]
,vfs.[io_stall_read_ms] AS [read_latency_ms]
,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]
,[size_on_disk_bytes]
,ISNULL([size_on_disk_bytes],0)/(1024*1024) AS [size_on_disk_mb]
FROM
sys.dm_io_virtual_file_stats(NULL,NULL) AS vfs
LEFT OUTER JOIN
sys.dm_user_db_resource_governance AS gov
ON vfs.[database_id] = gov.[database_id];
`
const sqlAzurePoolOsWaitStats = `
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. 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]
,(SELECT [elastic_pool_name] FROM sys.database_service_objectives WHERE database_id = DB_ID()) AS [elastic_pool_name]
,[wait_type]
,[waiting_tasks_count]
,[wait_time_ms]
,[max_wait_time_ms]
,[signal_wait_time_ms]
,[wait_time_ms]-[signal_wait_time_ms] AS [resource_wait_ms]
,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]
FROM sys.dm_os_wait_stats AS ws
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 sqlAzurePoolMemoryClerks = `
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. 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]
,(SELECT [elastic_pool_name] FROM sys.database_service_objectives WHERE database_id = DB_ID()) AS [elastic_pool_name]
,mc.[type] AS [clerk_type]
,SUM(mc.[pages_kb]) AS [size_kb]
FROM
sys.dm_os_memory_clerks AS mc
GROUP BY
mc.[type]
HAVING
SUM(mc.[pages_kb]) >= 1024
OPTION(RECOMPILE);
`
// Specific case on this query when cntr_type = 537003264 to return a percentage value between 0 and 100
// cf. https://docs.microsoft.com/en-us/sql/relational-databases/system-dynamic-management-views/sys-dm-os-performance-counters-transact-sql?view=azuresqldb-current
// Performance counters where the cntr_type column value is 537003264 display the ratio of a subset to its set as a percentage.
// For example, the Buffer Manager:Buffer cache hit ratio counter compares the total number of cache hits and the total number of cache lookups.
// As such, to get a snapshot-like reading of the last second only, you must compare the delta between the current value and the base value (denominator)
// between two collection points that are one second apart.
// The corresponding base value is the performance counter Buffer Manager:Buffer cache hit ratio base where the cntr_type column value is 1073939712.
const sqlAzurePoolPerformanceCounters = `
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. 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(pc.[object_name]) AS [object_name]
,RTRIM(pc.[counter_name]) AS [counter_name]
,ISNULL(gov.[database_name], RTRIM(pc.instance_name)) AS [instance_name]
,pc.[cntr_value] AS [cntr_value]
,pc.[cntr_type] AS [cntr_type]
FROM sys.dm_os_performance_counters AS pc
LEFT JOIN sys.dm_user_db_resource_governance AS gov
ON
TRY_CONVERT([uniqueidentifier], pc.[instance_name]) = gov.[physical_database_guid]
WHERE
/*filter out unnecessary SQL DB system database counters, other than master and tempdb*/
NOT (pc.[object_name] LIKE 'MSSQL%:Databases%' AND pc.[instance_name] IN ('model','model_masterdb','model_userdb','msdb','mssqlsystemresource'))
AND
(
pc.[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'
,'Query Store CPU usage'
) OR (
pc.[object_name] LIKE '%User Settable%'
OR pc.[object_name] LIKE '%SQL Errors%'
OR pc.[object_name] LIKE '%Batch Resp Statistics%'
) OR (
pc.[instance_name] IN ('_Total')
AND pc.[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 base.[cntr_value] > 0
THEN (pc.[cntr_value] * 1.0) / (base.[cntr_value] * 1.0) * 100
ELSE pc.[cntr_value]
END
AS float) AS [value]
,CAST(pc.[cntr_type] AS varchar(25)) AS [counter_type]
FROM @PCounters AS pc
LEFT OUTER JOIN @PCounters AS base
ON
pc.[counter_name] = REPLACE(base.[counter_name],' base','')
AND pc.[object_name] = base.[object_name]
AND pc.[instance_name] = base.[instance_name]
AND base.[cntr_type] = 1073939712
WHERE
pc.[cntr_type] <> 1073939712
OPTION(RECOMPILE)
`
const sqlAzurePoolSchedulers = `
IF SERVERPROPERTY('EngineEdition') <> 5
OR NOT EXISTS (SELECT 1 FROM sys.database_service_objectives WHERE database_id = DB_ID() AND elastic_pool_name IS NOT NULL) BEGIN
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure SQL database in an elastic pool. 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]
,(SELECT [elastic_pool_name] FROM sys.database_service_objectives WHERE database_id = DB_ID()) AS [elastic_pool_name]
,[scheduler_id]
,[cpu_id]
,[status]
,[is_online]
,[is_idle]
,[preemptive_switches_count]
,[context_switches_count]
,[idle_switches_count]
,[current_tasks_count]
,[runnable_tasks_count]
,[current_workers_count]
,[active_workers_count]
,[work_queue_count]
,[pending_disk_io_count]
,[load_factor]
,[failed_to_create_worker]
,[quantum_length_us]
,[yield_count]
,[total_cpu_usage_ms]
,[total_cpu_idle_capped_ms]
,[total_scheduler_delay_ms]
,[ideal_workers_limit]
FROM
sys.dm_os_schedulers;
`

View File

@ -0,0 +1,312 @@
package sqlserver
import (
"github.com/influxdata/telegraf/testutil"
"github.com/stretchr/testify/require"
"os"
"testing"
)
func TestAzureSQL_ElasticPool_ResourceStats_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolResourceStats"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
var acc testutil.Accumulator
require.NoError(t, server.Start(&acc))
require.NoError(t, server.Gather(&acc))
require.True(t, acc.HasMeasurement("sqlserver_pool_resource_stats"))
require.True(t, acc.HasTag("sqlserver_pool_resource_stats", "sql_instance"))
require.True(t, acc.HasTag("sqlserver_pool_resource_stats", "elastic_pool_name"))
require.True(t, acc.HasField("sqlserver_pool_resource_stats", "snapshot_time"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "avg_cpu_percent"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "avg_data_io_percent"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "avg_log_write_percent"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "avg_storage_percent"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "max_worker_percent"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "max_session_percent"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_stats", "storage_limit_mb"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "avg_instance_cpu_percent"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_stats", "avg_allocated_storage_percent"))
// This query should only return one row
require.Equal(t, 1, len(acc.Metrics))
server.Stop()
}
func TestAzureSQL_ElasticPool_ResourceGovernance_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolResourceGovernance"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
var acc testutil.Accumulator
require.NoError(t, server.Start(&acc))
require.NoError(t, server.Gather(&acc))
require.True(t, acc.HasMeasurement("sqlserver_pool_resource_governance"))
require.True(t, acc.HasTag("sqlserver_pool_resource_governance", "sql_instance"))
require.True(t, acc.HasTag("sqlserver_pool_resource_governance", "elastic_pool_name"))
require.True(t, acc.HasTag("sqlserver_pool_resource_governance", "slo_name"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "dtu_limit"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "cpu_limit"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "max_cpu"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "cap_cpu"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "max_db_memory"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "max_db_max_size_in_mb"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "db_file_growth_in_mb"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "log_size_in_mb"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "instance_cap_cpu"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "instance_max_log_rate"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "instance_max_worker_threads"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "checkpoint_rate_mbps"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "checkpoint_rate_io"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "primary_group_max_workers"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "primary_min_log_rate"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "primary_max_log_rate"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "primary_group_min_io"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "primary_group_max_io"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_governance", "primary_group_min_cpu"))
require.True(t, acc.HasFloatField("sqlserver_pool_resource_governance", "primary_group_max_cpu"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "primary_pool_max_workers"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "pool_max_io"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_local_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_managed_xstore_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_external_xstore_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_type_local_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_type_managed_xstore_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_type_external_xstore_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_pfs_iops"))
require.True(t, acc.HasInt64Field("sqlserver_pool_resource_governance", "volume_type_pfs_iops"))
// This query should only return one row
require.Equal(t, 1, len(acc.Metrics))
server.Stop()
}
func TestAzureSQL_ElasticPool_DatabaseIO_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolDatabaseIO"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
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", "elastic_pool_name"))
require.True(t, acc.HasTag("sqlserver_database_io", "database_name"))
require.True(t, acc.HasInt64Field("sqlserver_database_io", "database_id"))
require.True(t, acc.HasInt64Field("sqlserver_database_io", "file_id"))
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.HasInt64Field("sqlserver_database_io", "size_on_disk_bytes"))
require.True(t, acc.HasInt64Field("sqlserver_database_io", "size_on_disk_mb"))
server.Stop()
}
func TestAzureSQL_ElasticPool_OsWaitStats_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolOsWaitStats"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
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", "elastic_pool_name"))
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"))
server.Stop()
}
func TestAzureSQL_ElasticPool_MemoryClerks_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolMemoryClerks"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
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", "elastic_pool_name"))
require.True(t, acc.HasTag("sqlserver_memory_clerks", "clerk_type"))
require.True(t, acc.HasInt64Field("sqlserver_memory_clerks", "size_kb"))
server.Stop()
}
func TestAzureSQL_ElasticPool_PerformanceCounters_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolPerformanceCounters"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
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"))
server.Stop()
}
func TestAzureSQL_ElasticPool_Schedulers_Query(t *testing.T) {
if testing.Short() {
t.Skip("Skipping integration test in short mode")
}
if os.Getenv("AZURESQL_POOL_CONNECTION_STRING") == "" {
t.Skip("Missing environment variable AZURESQL_POOL_CONNECTION_STRING")
}
connectionString := os.Getenv("AZURESQL_POOL_CONNECTION_STRING")
server := &SQLServer{
Servers: []string{connectionString},
IncludeQuery: []string{"AzureSQLPoolSchedulers"},
AuthMethod: "connection_string",
DatabaseType: "AzureSQLPool",
}
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", "elastic_pool_name"))
require.True(t, acc.HasInt64Field("sqlserver_schedulers", "scheduler_id"))
require.True(t, acc.HasInt64Field("sqlserver_schedulers", "cpu_id"))
require.True(t, acc.HasTag("sqlserver_schedulers", "status"))
require.True(t, acc.HasField("sqlserver_schedulers", "is_online"))
require.True(t, acc.HasField("sqlserver_schedulers", "is_idle"))
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", "idle_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.HasField("sqlserver_schedulers", "failed_to_create_worker"))
require.True(t, acc.HasInt64Field("sqlserver_schedulers", "quantum_length_us"))
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_cpu_idle_capped_ms"))
require.True(t, acc.HasInt64Field("sqlserver_schedulers", "total_scheduler_delay_ms"))
require.True(t, acc.HasInt64Field("sqlserver_schedulers", "ideal_workers_limit"))
server.Stop()
}

View File

@ -54,6 +54,7 @@ const defaultServer = "Server=.;app name=telegraf;log=1;"
const (
typeAzureSQLDB = "AzureSQLDB"
typeAzureSQLManagedInstance = "AzureSQLManagedInstance"
typeAzureSQLPool = "AzureSQLPool"
typeSQLServer = "SQLServer"
)
@ -87,42 +88,34 @@ servers = [
## "database_type" enables a specific set of queries depending on the database type. If specified, it replaces azuredb = true/false and query_version = 2
## In the config file, the sql server plugin section should be repeated each with a set of servers for a specific database_type.
## Possible values for database_type are - "AzureSQLDB" or "AzureSQLManagedInstance" or "SQLServer"
## Possible values for database_type are - "SQLServer" or "AzureSQLDB" or "AzureSQLManagedInstance" or "AzureSQLPool"
database_type = "SQLServer"
## A list of queries to include. If not specified, all the below listed queries are used.
include_query = []
## A list of queries to explicitly ignore.
exclude_query = ["SQLServerAvailabilityReplicaStates", "SQLServerDatabaseReplicaStates"]
## Queries enabled by default for database_type = "SQLServer" are -
## SQLServerPerformanceCounters, SQLServerWaitStatsCategorized, SQLServerDatabaseIO, SQLServerProperties, SQLServerMemoryClerks,
## SQLServerSchedulers, SQLServerRequests, SQLServerVolumeSpace, SQLServerCpu, SQLServerAvailabilityReplicaStates, SQLServerDatabaseReplicaStates
## Queries enabled by default for database_type = "AzureSQLDB" are -
## AzureSQLDBResourceStats, AzureSQLDBResourceGovernance, AzureSQLDBWaitStats, AzureSQLDBDatabaseIO, AzureSQLDBServerProperties,
## AzureSQLDBOsWaitstats, AzureSQLDBMemoryClerks, AzureSQLDBPerformanceCounters, AzureSQLDBRequests, AzureSQLDBSchedulers
# database_type = "AzureSQLDB"
## A list of queries to include. If not specified, all the above listed queries are used.
# include_query = []
## A list of queries to explicitly ignore.
# exclude_query = []
## Queries enabled by default for database_type = "AzureSQLManagedInstance" are -
## AzureSQLMIResourceStats, AzureSQLMIResourceGovernance, AzureSQLMIDatabaseIO, AzureSQLMIServerProperties, AzureSQLMIOsWaitstats,
## AzureSQLMIMemoryClerks, AzureSQLMIPerformanceCounters, AzureSQLMIRequests, AzureSQLMISchedulers
# database_type = "AzureSQLManagedInstance"
## Queries enabled by default for database_type = "AzureSQLPool" are -
## AzureSQLPoolResourceStats, AzureSQLPoolResourceGovernance, AzureSQLPoolDatabaseIO, AzureSQLPoolWaitStats,
## AzureSQLPoolMemoryClerks, AzureSQLPoolPerformanceCounters, AzureSQLPoolSchedulers
# include_query = []
# exclude_query = []
## Queries enabled by default for database_type = "SQLServer" are -
## SQLServerPerformanceCounters, SQLServerWaitStatsCategorized, SQLServerDatabaseIO, SQLServerProperties, SQLServerMemoryClerks,
## SQLServerSchedulers, SQLServerRequests, SQLServerVolumeSpace, SQLServerCpu
database_type = "SQLServer"
include_query = []
## SQLServerAvailabilityReplicaStates and SQLServerDatabaseReplicaStates are optional queries and hence excluded here as default
exclude_query = ["SQLServerAvailabilityReplicaStates", "SQLServerDatabaseReplicaStates"]
## 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
## 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
## Optional parameter, setting this to 2 will use a new version
@ -156,9 +149,10 @@ func initQueries(s *SQLServer) error {
// New config option database_type
// To prevent query definition conflicts
// Constant defintiions for type "AzureSQLDB" start with sqlAzureDB
// Constant defintiions for type "AzureSQLManagedInstance" start with sqlAzureMI
// Constant defintiions for type "SQLServer" start with sqlServer
// 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 "SQLServer" start with sqlServer
if s.DatabaseType == typeAzureSQLDB {
queries["AzureSQLDBResourceStats"] = Query{ScriptName: "AzureSQLDBResourceStats", Script: sqlAzureDBResourceStats, ResultByRow: false}
queries["AzureSQLDBResourceGovernance"] = Query{ScriptName: "AzureSQLDBResourceGovernance", Script: sqlAzureDBResourceGovernance, ResultByRow: false}
@ -180,6 +174,14 @@ func initQueries(s *SQLServer) error {
queries["AzureSQLMIPerformanceCounters"] = Query{ScriptName: "AzureSQLMIPerformanceCounters", Script: sqlAzureMIPerformanceCounters, ResultByRow: false}
queries["AzureSQLMIRequests"] = Query{ScriptName: "AzureSQLMIRequests", Script: sqlAzureMIRequests, ResultByRow: false}
queries["AzureSQLMISchedulers"] = Query{ScriptName: "AzureSQLMISchedulers", Script: sqlAzureMISchedulers, ResultByRow: false}
} else if s.DatabaseType == typeAzureSQLPool {
queries["AzureSQLPoolResourceStats"] = Query{ScriptName: "AzureSQLPoolResourceStats", Script: sqlAzurePoolResourceStats, ResultByRow: false}
queries["AzureSQLPoolResourceGovernance"] = Query{ScriptName: "AzureSQLPoolResourceGovernance", Script: sqlAzurePoolResourceGovernance, ResultByRow: false}
queries["AzureSQLPoolDatabaseIO"] = Query{ScriptName: "AzureSQLPoolDatabaseIO", Script: sqlAzurePoolDatabaseIO, ResultByRow: false}
queries["AzureSQLPoolOsWaitStats"] = Query{ScriptName: "AzureSQLPoolOsWaitStats", Script: sqlAzurePoolOsWaitStats, ResultByRow: false}
queries["AzureSQLPoolMemoryClerks"] = Query{ScriptName: "AzureSQLPoolMemoryClerks", Script: sqlAzurePoolMemoryClerks, ResultByRow: false}
queries["AzureSQLPoolPerformanceCounters"] = Query{ScriptName: "AzureSQLPoolPerformanceCounters", Script: sqlAzurePoolPerformanceCounters, ResultByRow: false}
queries["AzureSQLPoolSchedulers"] = Query{ScriptName: "AzureSQLPoolSchedulers", Script: sqlAzurePoolSchedulers, 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}