Fix several issues with DatabaseIO query in sqlserver input (#7103)

This commit is contained in:
Giovanni Luisotto 2020-03-10 19:44:54 +00:00 committed by GitHub
parent a9d1726f99
commit 1601a06915
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
1 changed files with 62 additions and 41 deletions

View File

@ -352,53 +352,74 @@ EXEC(@SQL)
// EngineEdition=5 is Azure SQL DB // EngineEdition=5 is Azure SQL DB
const sqlDatabaseIOV2 = ` const sqlDatabaseIOV2 = `
SET DEADLOCK_PRIORITY -10; SET DEADLOCK_PRIORITY -10;
DECLARE @SqlStatement AS nvarchar(max);
IF SERVERPROPERTY('EngineEdition') = 5 IF SERVERPROPERTY('EngineEdition') = 5
BEGIN BEGIN
SELECT SET @SqlStatement = '
'sqlserver_database_io' As [measurement], SELECT
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], ''sqlserver_database_io'' As [measurement]
DB_NAME([vfs].[database_id]) AS [database_name], ,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance]
vfs.io_stall_read_ms AS read_latency_ms, ,DB_NAME([vfs].[database_id]) AS [database_name]
vfs.num_of_reads AS reads, ,vfs.io_stall_read_ms AS read_latency_ms
vfs.num_of_bytes_read AS read_bytes, ,vfs.num_of_reads AS reads
vfs.io_stall_write_ms AS write_latency_ms, ,vfs.num_of_bytes_read AS read_bytes
vfs.num_of_writes AS writes, ,vfs.io_stall_write_ms AS write_latency_ms
vfs.num_of_bytes_written AS write_bytes, ,vfs.num_of_writes AS writes
vfs.io_stall_queued_read_ms as rg_read_stall_ms, ,vfs.num_of_bytes_written AS write_bytes
vfs.io_stall_queued_write_ms as rg_write_stall_ms, ,vfs.io_stall_queued_read_ms as rg_read_stall_ms
ISNULL(b.name ,'RBPEX') as logical_filename, ,ISNULL(b.name ,''RBPEX'') as logical_filename
ISNULL(b.physical_name, 'RBPEX') as physical_filename, ,ISNULL(b.physical_name, ''RBPEX'') as physical_filename
CASE WHEN vfs.file_id = 2 THEN 'LOG'ELSE 'DATA' END AS file_type ,CASE WHEN vfs.file_id = 2 THEN ''LOG'' ELSE ''DATA'' END AS file_type
,ISNULL(size,0)/128 AS current_size_mb ,ISNULL(size,0)/128 AS current_size_mb
,ISNULL(FILEPROPERTY(b.name,'SpaceUsed')/128,0) as space_used_mb ,ISNULL(FILEPROPERTY(b.name,''SpaceUsed'')/128,0) as space_used_mb
FROM ,vfs.io_stall_queued_read_ms AS [rg_read_stall_ms]
[sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs ,vfs.io_stall_queued_write_ms AS [rg_write_stall_ms]
LEFT OUTER join sys.database_files b on b.file_id = vfs.file_id FROM [sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs
LEFT OUTER join sys.database_files b
ON b.file_id = vfs.file_id
'
EXEC sp_executesql @SqlStatement
END END
ELSE ELSE
BEGIN BEGIN
SELECT
'sqlserver_database_io' As [measurement], SET @SqlStatement = N'
REPLACE(@@SERVERNAME,'\',':') AS [sql_instance], SELECT
DB_NAME([vfs].[database_id]) [database_name], ''sqlserver_database_io'' AS [measurement]
vfs.io_stall_read_ms AS read_latency_ms, ,REPLACE(@@SERVERNAME,''\'','':'') AS [sql_instance]
vfs.num_of_reads AS reads, ,DB_NAME(vfs.[database_id]) AS [database_name]
vfs.num_of_bytes_read AS read_bytes, ,COALESCE(mf.[physical_name],''RBPEX'') AS [physical_filename] --RPBEX = Resilient Buffer Pool Extension
vfs.io_stall_write_ms AS write_latency_ms, ,COALESCE(mf.[name],''RBPEX'') AS [logical_filename] --RPBEX = Resilient Buffer Pool Extension
vfs.num_of_writes AS writes, ,mf.[type_desc] AS [file_type]
vfs.num_of_bytes_written AS write_bytes, ,IIF( RIGHT(vs.[volume_mount_point],1) = ''\'' /*Tag value cannot end with \ */
vfs.io_stall_queued_read_ms as rg_read_stall_ms, ,LEFT(vs.[volume_mount_point],LEN(vs.[volume_mount_point])-1)
vfs.io_stall_queued_write_ms as rg_write_stall_ms, ,vs.[volume_mount_point]
ISNULL(b.name ,'RBPEX') as logical_filename, ) AS [volume_mount_point]
ISNULL(b.physical_name, 'RBPEX') as physical_filename, ,vfs.[io_stall_read_ms] AS [read_latency_ms]
CASE WHEN vfs.file_id = 2 THEN 'LOG' ELSE 'DATA' END AS file_type ,vfs.[num_of_reads] AS [reads]
,ISNULL(size,0)/128 AS current_size_mb ,vfs.[num_of_bytes_read] AS [read_bytes]
-- can't easily get space used without switching context to each DB for MI/On-prem making query expensive ,vfs.[io_stall_write_ms] AS [write_latency_ms]
, -1 as space_used_mb ,vfs.[num_of_writes] AS [writes]
FROM ,vfs.[num_of_bytes_written] AS [write_bytes]
[sys].[dm_io_virtual_file_stats](NULL,NULL) AS vfs '
LEFT OUTER join sys.master_files b on b.database_id = vfs.database_id and b.file_id = vfs.file_id +
CASE
WHEN LEFT(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar) ,2) = '11'
/*SQL Server 2012 (ver 11.x) does not have [io_stall_queued_read_ms] and [io_stall_queued_write_ms]*/
THEN ''
ELSE N',vfs.io_stall_queued_read_ms AS [rg_read_stall_ms] ,vfs.io_stall_queued_write_ms AS [rg_write_stall_ms]'
END
+
N'FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs
INNER JOIN sys.master_files AS mf WITH (NOLOCK)
ON vfs.[database_id] = mf.[database_id] AND vfs.[file_id] = mf.[file_id]
CROSS APPLY sys.dm_os_volume_stats(vfs.[database_id], vfs.[file_id]) AS vs
'
EXEC sp_executesql @SqlStatement
END END
` `
// Conditional check based on Azure SQL DB, Azure SQL Managed instance OR On-prem SQL Server // Conditional check based on Azure SQL DB, Azure SQL Managed instance OR On-prem SQL Server