Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2,605 changes: 2,605 additions & 0 deletions examples/azure-sql-mi/grafana-dashboard/azure-sql-mi.json

Large diffs are not rendered by default.

Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
36 changes: 36 additions & 0 deletions examples/azure-sql-mi/mssql_mi_clerk.collector.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
# A collector defining memory clerk metrics for Microsoft SQL Server (Managed Instance).
#
# It is required that the SQL Server user has the following permissions:
#
# GRANT VIEW ANY DEFINITION TO
# GRANT VIEW SERVER STATE TO
#
collector_name: mssqlmi_clerk

# Similar to global.min_interval, but applies to the queries defined by this collector only.
#min_interval: 0s

metrics:
#
# Collected from sys.dm_os_memory_clerks
#
- metric_name: mssqlmi_clerk_size_kilobytes
type: gauge
help: 'Memory Clerk'
key_labels:
- clerk_type
values: [size_kb]
query_ref: mssqlmi_clerk

queries:
- query_name: mssqlmi_clerk
query: |
SELECT
mc.[type] AS [clerk_type]
,SUM(mc.[pages_kb]) AS [size_kb]
FROM sys.[dm_os_memory_clerks] AS mc WITH (NOLOCK)
GROUP BY
mc.[type]
HAVING
SUM(mc.[pages_kb]) >= 1024
OPTION(RECOMPILE);
226 changes: 226 additions & 0 deletions examples/azure-sql-mi/mssql_mi_perf.collector.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,226 @@
# A collector defining performance metrics for Microsoft SQL Server (Managed Instance).
#
# It is required that the SQL Server user has the following permissions:
#
# GRANT VIEW ANY DEFINITION TO
# GRANT VIEW SERVER STATE TO
#
collector_name: mssqlmi_perf

# Similar to global.min_interval, but applies to the queries defined by this collector only.
#min_interval: 0s

metrics:
#
# Collected from sys.dm_os_performance_counters
#
- metric_name: mssqlmi_perf_counter
type: counter
help: 'Performance counters'
key_labels:
- db
- object
- counter
values: [counter_value]
query_ref: mssqlmi_performance_counters

- metric_name: mssqlmi_perf_gauge
type: gauge
help: 'Performance gauges'
key_labels:
- db
- object
- gauge
values: [counter_value]
query_ref: mssqlmi_performance_gauges

queries:
- query_name: mssqlmi_performance_counters
query: |
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'sql_exporter - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance.';
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 (
-- following are all counters
-- from Databases object
'Transactions/sec'
,'Log Bytes Flushed/sec'
,'Log Flushes/sec'
-- from SQL Statistics object
,'Batch Requests/sec'
,'SQL Compilations/sec'
,'SQL Re-Compilations/sec'
-- from Access Methods object
,'Forwarded Records/sec'
,'Full Scans/sec'
,'Index Searches/sec'
,'Page Splits/sec'
,'Table Lock Escalations/sec'
,'Workfiles Created/sec'
,'Worktables Created/sec'
-- from General Statistics
,'Active Temp Tables'
,'Logins/sec'
,'Logouts/sec'
,'Logical Connections'
,'Processes blocked'
,'Temp Tables Creation Rate'
,'Temp Tables For Destruction'
,'User Connections'
-- from Buffer Manager
,'Background writer pages/sec'
,'Free list stalls/sec'
,'Lazy writes/sec'
,'Page lookups/sec'
,'Page reads/sec'
,'Page writes/sec'
,'Readahead pages/sec'
)
)
INSERT INTO @PCounters select * from PerfCounters
SELECT
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 [db]
,pc.[cntr_value] AS [counter_value]
from @PCounters pc
OPTION (RECOMPILE);

- query_name: mssqlmi_performance_gauges
query: |
SET DEADLOCK_PRIORITY -10;
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'sql_exporter - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance.';
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 '%:Buffer Manager'
OR RTRIM(spi.[object_name]) LIKE '%:Buffer Node'
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 (
-- following are all gauges
-- from Resource Pool Stats/Workload Group Stats objects
'CPU usage %'
,'CPU usage % base'
-- from Memory Manager object
--,'Memory Grants Outstanding'
--,'Memory Grants Pending'
,'Target Server Memory (KB)'
,'Total Server Memory (KB)'
-- from General Statistics
--,'Active Temp Tables'
--,'Logical Connections'
--,'Processes blocked'
--,'Temp Tables Creation Rate'
--,'Temp Tables For Destruction'
--,'User Connections'
-- from Buffer Manager
,'Page life expectancy'
)
)
INSERT INTO @PCounters select * from PerfCounters
SELECT
pc.[object_name] AS [object]
,pc.[counter_name] AS [gauge]
,CASE pc.[instance_name]
WHEN '_Total' THEN 'Total'
ELSE ISNULL(pc.[instance_name],'')
END AS [db]
,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 [counter_value]
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);
74 changes: 74 additions & 0 deletions examples/azure-sql-mi/mssql_mi_properties.collector.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
# A collector defining standard metrics for Microsoft SQL Server (Managed Instance).
#
# It is required that the SQL Server user has the following permissions:
#
# GRANT VIEW ANY DEFINITION TO
# GRANT VIEW SERVER STATE TO
#
collector_name: mssqlmi_properties

# Similar to global.min_interval, but applies to the queries defined by this collector only.
#min_interval: 0s

metrics:
#
# Collected from sys.server_resource_stats
#
- metric_name: mssqlmi_cpu_count
type: gauge
help: 'Virtual Cores'
values: [cpu_count]
query_ref: mssqlmi_properties

- metric_name: mssqlmi_server_memory_bytes
type: gauge
help: 'Server Memory in bytes'
values: [server_memory]
query_ref: mssqlmi_properties

- metric_name: mssqlmi_total_storage_bytes
type: gauge
help: 'Total Storage in bytes'
key_labels:
# populated from sku column
- sku
- hardware_type
values: [total_storage]
query_ref: mssqlmi_properties

- metric_name: mssqlmi_available_storage_bytes
type: gauge
help: 'Available Storage in bytes'
values: [available_storage]
query_ref: mssqlmi_properties

- metric_name: mssqlmi_db_online
type: gauge
help: '# of Online Databases'
values: [db_online]
query_ref: mssqlmi_properties

queries:
- query_name: mssqlmi_properties
query: |
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'sql_exporter - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT TOP 1
[virtual_core_count] AS [cpu_count]
,(SELECT [process_memory_limit_mb]*1000000 FROM sys.dm_os_job_object) AS [server_memory]
,[sku]
,[hardware_generation] AS [hardware_type]
,cast([reserved_storage_mb]*1000000 as bigint) AS [total_storage]
,cast(([reserved_storage_mb] - [storage_space_used_mb])*1000000 as bigint) AS [available_storage]
,[db_online]
FROM sys.server_resource_stats
CROSS APPLY (
SELECT
SUM( CASE WHEN [state] = 0 THEN 1 ELSE 0 END ) AS [db_online]
FROM sys.databases
) AS dbs
ORDER BY
[start_time] DESC;
49 changes: 49 additions & 0 deletions examples/azure-sql-mi/mssql_mi_size.collector.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,49 @@
# A collector defining database size metrics for Microsoft SQL Server (Managed Instance).
#
# It is required that the SQL Server user has the following permissions:
#
# GRANT VIEW ANY DEFINITION TO
# GRANT VIEW SERVER STATE TO
#
collector_name: mssqlmi_size

# Similar to global.min_interval, but applies to the queries defined by this collector only.
#min_interval: 0s

metrics:
#
# Collected from sys.dm_io_virtual_file_stats
#
- metric_name: mssqlmi_database_size_bytes
type: gauge
help: 'Database Size in Bytes'
key_labels:
- database
- file_type
values: [size_on_disk_bytes]
query_ref: mssqlmi_size

queries:
- query_name: mssqlmi_size
query: |
IF SERVERPROPERTY('EngineEdition') <> 8 BEGIN /*not Azure Managed Instance*/
DECLARE @ErrorMessage AS nvarchar(500) = 'sql_exporter - Connection string Server:'+ @@SERVERNAME + ',Database:' + DB_NAME() +' is not an Azure Managed Instance.';
RAISERROR (@ErrorMessage,11,1)
RETURN
END
SELECT
DB_NAME(mf.database_id) AS [database]
-- ,name AS 'File Logical Name'
,'file_type' = CASE WHEN type_desc = 'LOG' THEN 'Log File' WHEN type_desc = 'ROWS' THEN 'Data File' ELSE type_desc END
-- ,mf.physical_name AS 'File Physical Name'
,size_on_disk_bytes
-- ,size_on_disk_bytes/ 1024 AS 'Size(KB)'
-- size_on_disk_bytes/ 1024 / 1024 AS 'Size(MB)',
-- size_on_disk_bytes/ 1024 / 1024 / 1024 AS 'Size(GB)'
FROM
sys.dm_io_virtual_file_stats(NULL, NULL) AS divfs
JOIN sys.master_files AS mf
ON mf.database_id = divfs.database_id
AND mf.file_id = divfs.file_id
WHERE DB_NAME(mf.database_id) NOT IN ('master', 'model','tempdb', 'msdb')
-- ORDER BY size_on_disk_bytes DESC
Loading