feat(inputs/sqlserver): add RecentBackups query (#10567)

This commit is contained in:
Aleksandr Venger 2022-04-13 18:57:36 +03:00 committed by GitHub
parent f43ceb2437
commit 237658d6cd
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
3 changed files with 52 additions and 1 deletions

View File

@ -120,7 +120,8 @@ Remove User Id and Password keywords from the connection string in your config f
## Queries enabled by default for database_type = "SQLServer" are -
## SQLServerPerformanceCounters, SQLServerWaitStatsCategorized, SQLServerDatabaseIO, SQLServerProperties, SQLServerMemoryClerks,
## SQLServerSchedulers, SQLServerRequests, SQLServerVolumeSpace, SQLServerCpu, SQLServerAvailabilityReplicaStates, SQLServerDatabaseReplicaStates
## SQLServerSchedulers, SQLServerRequests, SQLServerVolumeSpace, SQLServerCpu, SQLServerAvailabilityReplicaStates, SQLServerDatabaseReplicaStates,
## SQLServerRecentBackups
## Queries enabled by default for database_type = "AzureSQLDB" are -
## AzureSQLDBResourceStats, AzureSQLDBResourceGovernance, AzureSQLDBWaitStats, AzureSQLDBDatabaseIO, AzureSQLDBServerProperties,
@ -198,6 +199,7 @@ Remove User Id and Password keywords from the connection string in your config f
## - SQLServerRequests
## - SQLServerVolumeSpace
## - SQLServerCpu
## - SQLServerRecentBackups
## and following as optional (if mentioned in the include_query list)
## - SQLServerAvailabilityReplicaStates
## - SQLServerDatabaseReplicaStates
@ -381,6 +383,7 @@ These are metrics for Azure SQL to monitor resources usage at Elastic Pool level
- 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
- SQLServerRecentBackups: Collects latest full, differential and transaction log backup date and size from `msdb.dbo.backupset`
### Output Measures

View File

@ -127,6 +127,7 @@ func (s *SQLServer) initQueries() error {
queries["SQLServerCpu"] = Query{ScriptName: "SQLServerCpu", Script: sqlServerRingBufferCPU, ResultByRow: false}
queries["SQLServerAvailabilityReplicaStates"] = Query{ScriptName: "SQLServerAvailabilityReplicaStates", Script: sqlServerAvailabilityReplicaStates, ResultByRow: false}
queries["SQLServerDatabaseReplicaStates"] = Query{ScriptName: "SQLServerDatabaseReplicaStates", Script: sqlServerDatabaseReplicaStates, ResultByRow: false}
queries["SQLServerRecentBackups"] = Query{ScriptName: "SQLServerRecentBackups", Script: sqlServerRecentBackups, ResultByRow: false}
} else {
// If this is an AzureDB instance, grab some extra metrics
if s.AzureDB {

View File

@ -1334,3 +1334,50 @@ END'
EXEC sp_executesql @SqlStatement
`
const sqlServerRecentBackups string = `
IF SERVERPROPERTY('EngineEdition') NOT IN (2,3,4) BEGIN /*NOT IN Standard,Enterpris,Express*/
DECLARE @ErrorMessage AS nvarchar(500) = 'Telegraf - Connection string Server:'+ @@ServerName + ',Database:' + DB_NAME() +' is not a SQL Server Standard,Enterprise or Express. Check the database_type parameter in the telegraf configuration.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END;
WITH MostRecentBackups AS
(
SELECT
database_name AS [Database],
MAX(bus.backup_finish_date) AS LastBackupTime,
CASE bus.type
WHEN 'D' THEN 'Full'
WHEN 'I' THEN 'Differential'
WHEN 'L' THEN 'Transaction Log'
END AS Type
FROM msdb.dbo.backupset bus
WHERE bus.type <> 'F'
GROUP BY bus.database_name,bus.type
),
BackupsWithSize AS
(
SELECT mrb.*, CAST((SELECT TOP 1 b.backup_size FROM msdb.dbo.backupset b WHERE [Database] = b.database_name AND LastBackupTime = b.backup_finish_date) AS int) AS [backup_size]
FROM MostRecentBackups mrb
)
SELECT
'sqlserver_recentbackup' AS [measurement],
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance],
d.name AS [database_name],
d.database_id as [database_id],
d.state_desc AS [state],
d.recovery_model_desc AS [recovery_model],
DATEDIFF(SECOND,{d '1970-01-01'}, bf.LastBackupTime) AS [last_full_backup_time],
bf.backup_size AS [full_backup_size_bytes],
DATEDIFF(SECOND,{d '1970-01-01'}, bd.LastBackupTime) AS [last_differential_backup_time],
bd.backup_size AS [differential_backup_size_bytes],
DATEDIFF(SECOND,{d '1970-01-01'}, bt.LastBackupTime) AS [last_transaction_log_backup_time],
bt.backup_size AS [transaction_log_backup_size_bytes]
FROM sys.databases d
LEFT JOIN BackupsWithSize bf ON (d.name = bf.[Database] AND (bf.Type = 'Full' OR bf.Type IS NULL))
LEFT JOIN BackupsWithSize bd ON (d.name = bd.[Database] AND (bd.Type = 'Differential' OR bd.Type IS NULL))
LEFT JOIN BackupsWithSize bt ON (d.name = bt.[Database] AND (bt.Type = 'Transaction Log' OR bt.Type IS NULL))
WHERE d.name <> 'tempdb' AND d.source_database_id IS NULL
`