Add Database IO Tempdb per Azure DB and fix PerfmonV2 collection for on-prem (#7163)

This commit is contained in:
denzilribeiro 2020-03-16 15:32:30 -05:00 committed by GitHub
parent 9508bbdf29
commit 0a75dea70d
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
1 changed files with 153 additions and 122 deletions

View File

@ -359,24 +359,40 @@ BEGIN
SELECT SELECT
''sqlserver_database_io'' As [measurement] ''sqlserver_database_io'' As [measurement]
,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance] ,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance]
,DB_NAME([vfs].[database_id]) AS [database_name] ,DB_NAME() as database_name
,vfs.database_id -- /*needed as tempdb is different for each Azure SQL DB as grouping has to be by logical server + db_name + database_id*/
,vfs.file_id
,vfs.io_stall_read_ms AS read_latency_ms ,vfs.io_stall_read_ms AS read_latency_ms
,vfs.num_of_reads AS reads ,vfs.num_of_reads AS reads
,vfs.num_of_bytes_read AS read_bytes ,vfs.num_of_bytes_read AS read_bytes
,vfs.io_stall_write_ms AS write_latency_ms ,vfs.io_stall_write_ms AS write_latency_ms
,vfs.num_of_writes AS writes ,vfs.num_of_writes AS writes
,vfs.num_of_bytes_written AS write_bytes ,vfs.num_of_bytes_written AS write_bytes
,vfs.io_stall_queued_read_ms as rg_read_stall_ms
,ISNULL(b.name ,''RBPEX'') as logical_filename
,ISNULL(b.physical_name, ''RBPEX'') as physical_filename
,CASE WHEN vfs.file_id = 2 THEN ''LOG'' ELSE ''DATA'' END AS file_type
,ISNULL(size,0)/128 AS current_size_mb
,ISNULL(FILEPROPERTY(b.name,''SpaceUsed'')/128,0) as space_used_mb
,vfs.io_stall_queued_read_ms AS [rg_read_stall_ms] ,vfs.io_stall_queued_read_ms AS [rg_read_stall_ms]
,vfs.io_stall_queued_write_ms AS [rg_write_stall_ms] ,vfs.io_stall_queued_write_ms AS [rg_write_stall_ms]
,CASE
WHEN (vfs.database_id = 0) THEN ''RBPEX''
ELSE b.logical_filename
END as logical_filename
,CASE
WHEN (vfs.database_id = 0) THEN ''RBPEX''
ELSE b.physical_filename
END as physical_filename
,CASE WHEN vfs.file_id = 2 THEN ''LOG'' ELSE ''DATA'' END AS file_type
,ISNULL(size,0)/128 AS current_size_mb
,ISNULL(FILEPROPERTY(b.logical_filename,''SpaceUsed'')/128,0) as space_used_mb
FROM [sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs FROM [sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs
LEFT OUTER join sys.database_files b -- needed to get Tempdb file names on Azure SQL DB so you can join appropriately. Without this had a bug where join was only on file_id
ON b.file_id = vfs.file_id LEFT OUTER join
(
SELECT DB_ID() as database_id, file_id, logical_filename=name COLLATE SQL_Latin1_General_CP1_CI_AS
, physical_filename = physical_name COLLATE SQL_Latin1_General_CP1_CI_AS, size from sys.database_files
where type <> 2
UNION ALL
SELECT 2 as database_id, file_id, logical_filename = name , physical_filename = physical_name, size
from tempdb.sys.database_files
) b ON b.database_id = vfs.database_id and b.file_id = vfs.file_id
where vfs.database_id IN (DB_ID(),0,2)
' '
EXEC sp_executesql @SqlStatement EXEC sp_executesql @SqlStatement
@ -536,135 +552,150 @@ DECLARE @PCounters TABLE
cntr_type INT, cntr_type INT,
Primary Key(object_name, counter_name, instance_name) Primary Key(object_name, counter_name, instance_name)
); );
INSERT INTO @PCounters
SELECT DISTINCT DECLARE @SQL NVARCHAR(MAX)
SET @SQL = N'SELECT DISTINCT
RTrim(spi.object_name) object_name, RTrim(spi.object_name) object_name,
RTrim(spi.counter_name) counter_name, RTrim(spi.counter_name) counter_name,'
CASE WHEN ( +
RTRIM(spi.object_name) LIKE '%:Databases' CASE
OR RTRIM(spi.object_name) LIKE '%:Database Replica' WHEN CAST(SERVERPROPERTY('EngineEdition') AS int) IN (5,8) --- needed to get actual DB Name for SQL DB/ Managed instance
OR RTRIM(spi.object_name) LIKE '%:Catalog Metadata' THEN N'CASE WHEN (
OR RTRIM(spi.object_name) LIKE '%:Query Store' RTRIM(spi.object_name) LIKE ''%:Databases''
OR RTRIM(spi.object_name) LIKE '%:Columnstore' OR RTRIM(spi.object_name) LIKE ''%:Database Replica''
OR RTRIM(spi.object_name) LIKE '%:Advanced Analytics') OR RTRIM(spi.object_name) LIKE ''%:Catalog Metadata''
AND SERVERPROPERTY ('EngineEdition') IN (5,8) OR RTRIM(spi.object_name) LIKE ''%:Query Store''
AND TRY_CONVERT(uniqueidentifier, spi.instance_name) IS NOT NULL -- for cloud only 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 d.name THEN d.name
WHEN RTRIM(object_name) LIKE '%:Availability Replica' WHEN RTRIM(object_name) LIKE ''%:Availability Replica''
AND SERVERPROPERTY ('EngineEdition') IN (5,8)
AND TRY_CONVERT(uniqueidentifier, spi.instance_name) IS NOT NULL -- for cloud only AND TRY_CONVERT(uniqueidentifier, spi.instance_name) IS NOT NULL -- for cloud only
THEN d.name + RTRIM(SUBSTRING(spi.instance_name, 37, LEN(spi.instance_name))) THEN d.name + RTRIM(SUBSTRING(spi.instance_name, 37, LEN(spi.instance_name)))
ELSE spi.instance_name ELSE spi.instance_name
END AS instance_name, END AS instance_name,'
CAST(spi.cntr_value AS BIGINT) AS cntr_value, ELSE 'spi.instance_name as instance_name, '
END
+
'CAST(spi.cntr_value AS BIGINT) AS cntr_value,
spi.cntr_type spi.cntr_type
FROM sys.dm_os_performance_counters AS spi 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
WHEN CAST(SERVERPROPERTY('EngineEdition') AS int) IN (5,8) --- Join is ONLY for managed instance and SQL DB, not for on-prem
THEN CAST(N'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 WHEN -- in SQL DB standalone, physical_database_name for master is the GUID of the user database = CASE WHEN -- in SQL DB standalone, physical_database_name for master is the GUID of the user database
d.name = 'master' AND TRY_CONVERT(uniqueidentifier, d.physical_database_name) IS NOT NULL d.name = ''master'' AND TRY_CONVERT(uniqueidentifier, d.physical_database_name) IS NOT NULL
THEN d.name THEN d.name
ELSE d.physical_database_name ELSE d.physical_database_name
END END ' as NVARCHAR(MAX))
WHERE ( ELSE N' '
counter_name IN ( END
'SQL Compilations/sec',
'SQL Re-Compilations/sec', SET @SQL = @SQL + CAST(N' WHERE (
'User Connections', counter_name IN (
'Batch Requests/sec', ''SQL Compilations/sec'',
'Logouts/sec', ''SQL Re-Compilations/sec'',
'Logins/sec', ''User Connections'',
'Processes blocked', ''Batch Requests/sec'',
'Latch Waits/sec', ''Logouts/sec'',
'Full Scans/sec', ''Logins/sec'',
'Index Searches/sec', ''Processes blocked'',
'Page Splits/sec', ''Latch Waits/sec'',
'Page lookups/sec', ''Full Scans/sec'',
'Page reads/sec', ''Index Searches/sec'',
'Page writes/sec', ''Page Splits/sec'',
'Readahead pages/sec', ''Page lookups/sec'',
'Lazy writes/sec', ''Page reads/sec'',
'Checkpoint pages/sec', ''Page writes/sec'',
'Page life expectancy', ''Readahead pages/sec'',
'Log File(s) Size (KB)', ''Lazy writes/sec'',
'Log File(s) Used Size (KB)', ''Checkpoint pages/sec'',
'Data File(s) Size (KB)', ''Page life expectancy'',
'Transactions/sec', ''Log File(s) Size (KB)'',
'Write Transactions/sec', ''Log File(s) Used Size (KB)'',
'Active Temp Tables', ''Data File(s) Size (KB)'',
'Temp Tables Creation Rate', ''Transactions/sec'',
'Temp Tables For Destruction', ''Write Transactions/sec'',
'Free Space in tempdb (KB)', ''Active Temp Tables'',
'Version Store Size (KB)', ''Temp Tables Creation Rate'',
'Memory Grants Pending', ''Temp Tables For Destruction'',
'Memory Grants Outstanding', ''Free Space in tempdb (KB)'',
'Free list stalls/sec', ''Version Store Size (KB)'',
'Buffer cache hit ratio', ''Memory Grants Pending'',
'Buffer cache hit ratio base', ''Memory Grants Outstanding'',
'Backup/Restore Throughput/sec', ''Free list stalls/sec'',
'Total Server Memory (KB)', ''Buffer cache hit ratio'',
'Target Server Memory (KB)', ''Buffer cache hit ratio base'',
'Log Flushes/sec', ''Backup/Restore Throughput/sec'',
'Log Flush Wait Time', ''Total Server Memory (KB)'',
'Memory broker clerk size', ''Target Server Memory (KB)'',
'Log Bytes Flushed/sec', ''Log Flushes/sec'',
'Bytes Sent to Replica/sec', ''Log Flush Wait Time'',
'Log Send Queue', ''Memory broker clerk size'',
'Bytes Sent to Transport/sec', ''Log Bytes Flushed/sec'',
'Sends to Replica/sec', ''Bytes Sent to Replica/sec'',
'Bytes Sent to Transport/sec', ''Log Send Queue'',
'Sends to Transport/sec', ''Bytes Sent to Transport/sec'',
'Bytes Received from Replica/sec', ''Sends to Replica/sec'',
'Receives from Replica/sec', ''Bytes Sent to Transport/sec'',
'Flow Control Time (ms/sec)', ''Sends to Transport/sec'',
'Flow Control/sec', ''Bytes Received from Replica/sec'',
'Resent Messages/sec', ''Receives from Replica/sec'',
'Redone Bytes/sec', ''Flow Control Time (ms/sec)'',
'XTP Memory Used (KB)', ''Flow Control/sec'',
'Transaction Delay', ''Resent Messages/sec'',
'Log Bytes Received/sec', ''Redone Bytes/sec'',
'Log Apply Pending Queue', ''XTP Memory Used (KB)'',
'Redone Bytes/sec', ''Transaction Delay'',
'Recovery Queue', ''Log Bytes Received/sec'',
'Log Apply Ready Queue', ''Log Apply Pending Queue'',
'CPU usage %', ''Redone Bytes/sec'',
'CPU usage % base', ''Recovery Queue'',
'Queued requests', ''Log Apply Ready Queue'',
'Requests completed/sec', ''CPU usage %'',
'Blocked tasks', ''CPU usage % base'',
'Active memory grant amount (KB)', ''Queued requests'',
'Disk Read Bytes/sec', ''Requests completed/sec'',
'Disk Read IO Throttled/sec', ''Blocked tasks'',
'Disk Read IO/sec', ''Active memory grant amount (KB)'',
'Disk Write Bytes/sec', ''Disk Read Bytes/sec'',
'Disk Write IO Throttled/sec', ''Disk Read IO Throttled/sec'',
'Disk Write IO/sec', ''Disk Read IO/sec'',
'Used memory (KB)', ''Disk Write Bytes/sec'',
'Forwarded Records/sec', ''Disk Write IO Throttled/sec'',
'Background Writer pages/sec', ''Disk Write IO/sec'',
'Percent Log Used', ''Used memory (KB)'',
'Log Send Queue KB', ''Forwarded Records/sec'',
'Redo Queue KB', ''Background Writer pages/sec'',
'Mirrored Write Transactions/sec', ''Percent Log Used'',
'Group Commit Time', ''Log Send Queue KB'',
'Group Commits/Sec' ''Redo Queue KB'',
) ''Mirrored Write Transactions/sec'',
) OR ( ''Group Commit Time'',
object_name LIKE '%User Settable%' ''Group Commits/Sec''
OR object_name LIKE '%SQL Errors%' )
) OR ( ) OR (
object_name LIKE '%Batch Resp Statistics%' object_name LIKE ''%User Settable%''
) OR ( OR object_name LIKE ''%SQL Errors%''
instance_name IN ('_Total') ) OR (
AND counter_name IN ( object_name LIKE ''%Batch Resp Statistics%''
'Lock Timeouts/sec', ) OR (
'Number of Deadlocks/sec', instance_name IN (''_Total'')
'Lock Waits/sec', AND counter_name IN (
'Latch Waits/sec' ''Lock Timeouts/sec'',
) ''Number of Deadlocks/sec'',
) ''Lock Waits/sec'',
''Latch Waits/sec''
)
)
' as NVARCHAR(MAX))
INSERT INTO @PCounters
EXEC (@SQL)
DECLARE @SQL NVARCHAR(MAX)
SET @SQL = REPLACE('SELECT SET @SQL = REPLACE('SELECT
"SQLServer:Workload Group Stats" AS object, "SQLServer:Workload Group Stats" AS object,
counter, counter,