Skip to content

Commit

Permalink
Sql Server - Disk Space Measurement (influxdata#7214)
Browse files Browse the repository at this point in the history
  • Loading branch information
Trovalo authored and idohalevi committed Sep 23, 2020
1 parent 213de65 commit 5030189
Show file tree
Hide file tree
Showing 3 changed files with 100 additions and 52 deletions.
29 changes: 19 additions & 10 deletions plugins/inputs/sqlserver/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -48,27 +48,35 @@ GO

## Optional parameter, setting this to 2 will use a new version
## of the collection queries that break compatibility with the original
## dashboards. All new functionality is under V2
## dashboards.
## Version 2 - is compatible from SQL Server 2012 and later versions and also for SQL Azure DB
query_version = 2

## If you are using AzureDB, setting this to true will gather resource utilization metrics
# azuredb = true
# azuredb = false

## Possible queries:
## Possible queries
## Version 2:
## - PerformanceCounters
## - WaitStatsCategorized
## - DatabaseIO
## - DatabaseProperties
## - ServerProperties
## - MemoryClerk
## - Schedulers
## - SqlRequests
## - VolumeSpace
## Version 1:
## - PerformanceCounters
## - WaitStatsCategorized
## - CPUHistory
## - DatabaseIO
## - DatabaseSize
## - DatabaseStats
## - DatabaseProperties
## - MemoryClerk
## - VolumeSpace
## - Schedulers
## - AzureDBResourceStats
## - AzureDBResourceGovernance
## - SqlRequests
## - ServerProperties
## - PerformanceMetrics

## A list of queries to include. If not specified, all the above listed queries are used.
# include_query = []

Expand All @@ -79,7 +87,7 @@ GO
### 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 are written in such a way as to only gather SQL specific metrics (no disk space or overall CPU related metrics) and they only report raw metrics, no math has been done to calculate deltas. To graph this data you must calculate deltas in your dashboarding software.
**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 are written in such a way as to only gather SQL specific metrics (no overall CPU related metrics) and they 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 (deprecated in 1.6):
The original metrics queries provide:
Expand Down Expand Up @@ -115,6 +123,7 @@ The new (version 2) metrics provide:
- *SqlRequests* - This captures a snapshot of dm_exec_requests and
dm_exec_sessions that gives you running requests as well as wait types and
blocking sessions.
- *VolumeSpace* - 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.

In order to allow tracking on a per statement basis this query produces a
unique tag for each query. Depending on the database workload, this may
Expand Down
119 changes: 79 additions & 40 deletions plugins/inputs/sqlserver/sqlserver.go
Original file line number Diff line number Diff line change
Expand Up @@ -35,46 +35,53 @@ type MapQuery map[string]Query
const defaultServer = "Server=.;app name=telegraf;log=1;"

const sampleConfig = `
## Specify instances to monitor with a list of connection strings.
## All connection parameters are optional.
## By default, the host is localhost, listening on default port, TCP 1433.
## for Windows, the user is the currently running AD user (SSO).
## See https://github.com/denisenkom/go-mssqldb for detailed connection
## parameters, in particular, tls connections can be created like so:
## "encrypt=true;certificate=<cert>;hostNameInCertificate=<SqlServer host fqdn>"
# servers = [
# "Server=192.168.1.10;Port=1433;User Id=<user>;Password=<pw>;app name=telegraf;log=1;",
# ]
## Optional parameter, setting this to 2 will use a new version
## of the collection queries that break compatibility with the original
## dashboards.
query_version = 2
## If you are using AzureDB, setting this to true will gather resource utilization metrics
# azuredb = false
## Possible queries:
## - PerformanceCounters
## - WaitStatsCategorized
## - DatabaseIO
## - DatabaseProperties
## - CPUHistory
## - DatabaseSize
## - DatabaseStats
## - MemoryClerk
## - VolumeSpace
## - PerformanceMetrics
## - Schedulers
## - AzureDBResourceStats
## - AzureDBResourceGovernance
## - SqlRequests
## - ServerProperties
## 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 = [ 'Schedulers' , 'SqlRequests']
## Specify instances to monitor with a list of connection strings.
## All connection parameters are optional.
## By default, the host is localhost, listening on default port, TCP 1433.
## for Windows, the user is the currently running AD user (SSO).
## See https://github.com/denisenkom/go-mssqldb for detailed connection
## parameters, in particular, tls connections can be created like so:
## "encrypt=true;certificate=<cert>;hostNameInCertificate=<SqlServer host fqdn>"
# servers = [
# "Server=192.168.1.10;Port=1433;User Id=<user>;Password=<pw>;app name=telegraf;log=1;",
# ]
## Optional parameter, setting this to 2 will use a new version
## of the collection queries that break compatibility with the original
## dashboards.
## Version 2 - is compatible from SQL Server 2012 and later versions and also for SQL Azure DB
query_version = 2
## If you are using AzureDB, setting this to true will gather resource utilization metrics
# azuredb = false
## Possible queries
## Version 2:
## - PerformanceCounters
## - WaitStatsCategorized
## - DatabaseIO
## - ServerProperties
## - MemoryClerk
## - Schedulers
## - SqlRequests
## - VolumeSpace
## Version 1:
## - PerformanceCounters
## - WaitStatsCategorized
## - CPUHistory
## - DatabaseIO
## - DatabaseSize
## - DatabaseStats
## - DatabaseProperties
## - MemoryClerk
## - VolumeSpace
## - PerformanceMetrics
## 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 = [ 'Schedulers' , 'SqlRequests']
`

// SampleConfig return the sample configuration
Expand Down Expand Up @@ -109,6 +116,7 @@ func initQueries(s *SQLServer) error {
queries["MemoryClerk"] = Query{Script: sqlMemoryClerkV2, ResultByRow: false}
queries["Schedulers"] = Query{Script: sqlServerSchedulersV2, ResultByRow: false}
queries["SqlRequests"] = Query{Script: sqlServerRequestsV2, ResultByRow: false}
queries["VolumeSpace"] = Query{Script: sqlServerVolumeSpaceV2, ResultByRow: false}
} else {
queries["PerformanceCounters"] = Query{Script: sqlPerformanceCounters, ResultByRow: true}
queries["WaitStatsCategorized"] = Query{Script: sqlWaitStatsCategorized, ResultByRow: false}
Expand Down Expand Up @@ -1554,6 +1562,37 @@ SELECT
`

const sqlServerVolumeSpaceV2 string = `
/* Only for on-prem version of SQL Server
Gets data about disk space, only if the disk is used by SQL Server
EngineEdition:
1 = Personal or Desktop Engine
2 = Standard
3 = Enterprise
4 = Express
5 = SQL Database
6 = SQL Data Warehouse
8 = Managed Instance
*/
IF SERVERPROPERTY('EngineEdition') NOT IN (5,8)
BEGIN
SELECT DISTINCT
'sqlserver_disk_space' AS [measurement]
,SERVERPROPERTY('machinename') AS [server_name]
,REPLACE(@@SERVERNAME,'\',':') AS [sql_instance]
,IIF( RIGHT(vs.[volume_mount_point],1) = '\' /*Tag value cannot end with \ */
,LEFT(vs.[volume_mount_point],LEN(vs.[volume_mount_point])-1)
,vs.[volume_mount_point]
) AS [volume_mount_point]
,vs.[total_bytes] AS [total_space_bytes]
,vs.[available_bytes] AS [available_space_bytes]
,vs.[total_bytes] - vs.[available_bytes] AS [used_space_bytes]
FROM
sys.master_files as mf
CROSS APPLY sys.dm_os_volume_stats(mf.database_id, mf.file_id) as vs
END
`

// Queries V1
const sqlPerformanceMetrics string = `SET DEADLOCK_PRIORITY -10;
SET NOCOUNT ON;
Expand Down
4 changes: 2 additions & 2 deletions plugins/inputs/sqlserver/sqlserver_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -16,13 +16,13 @@ func TestSqlServer_QueriesInclusionExclusion(t *testing.T) {
cases := []map[string]interface{}{
{
"IncludeQuery": []string{},
"ExcludeQuery": []string{"WaitStatsCategorized", "DatabaseIO", "ServerProperties", "MemoryClerk", "Schedulers"},
"ExcludeQuery": []string{"WaitStatsCategorized", "DatabaseIO", "ServerProperties", "MemoryClerk", "Schedulers", "VolumeSpace"},
"queries": []string{"PerformanceCounters", "SqlRequests"},
"queriesTotal": 2,
},
{
"IncludeQuery": []string{"PerformanceCounters", "SqlRequests"},
"ExcludeQuery": []string{"SqlRequests", "WaitStatsCategorized", "DatabaseIO"},
"ExcludeQuery": []string{"SqlRequests", "WaitStatsCategorized", "DatabaseIO", "VolumeSpace"},
"queries": []string{"PerformanceCounters"},
"queriesTotal": 1,
},
Expand Down

0 comments on commit 5030189

Please sign in to comment.