From 49582023eef3249da9a88af4db5afb0122eaf3be Mon Sep 17 00:00:00 2001 From: Erik Darling <2136037+erikdarlingdata@users.noreply.github.com> Date: Wed, 3 Apr 2024 15:25:27 -0400 Subject: [PATCH] Update sp_PressureDetector.sql Well that was an afternoon. Sampled disk metrics are fixed now. --- sp_PressureDetector/sp_PressureDetector.sql | 142 ++++++++++++++++---- 1 file changed, 116 insertions(+), 26 deletions(-) diff --git a/sp_PressureDetector/sp_PressureDetector.sql b/sp_PressureDetector/sp_PressureDetector.sql index 3acb9ce..3d90063 100644 --- a/sp_PressureDetector/sp_PressureDetector.sql +++ b/sp_PressureDetector/sp_PressureDetector.sql @@ -395,11 +395,15 @@ OPTION(MAXDOP 1, RECOMPILE);', database_file_details nvarchar(1000), file_size_gb decimal(38,2), total_gb_read decimal(38,2), + total_mb_read decimal(38,2), total_read_count bigint, avg_read_stall_ms decimal(38,2), total_gb_written decimal(38,2), + total_mb_written decimal(38,2), total_write_count bigint, avg_write_stall_ms decimal(38,2), + io_stall_read_ms bigint, + io_stall_write_ms bigint, sample_time datetime ); @@ -908,6 +912,16 @@ OPTION(MAXDOP 1, RECOMPILE);', ) ELSE 0 END, + total_mb_read = + CASE + WHEN vfs.num_of_bytes_read > 0 + THEN CONVERT + ( + decimal(38, 2), + vfs.num_of_bytes_read / 1048576. + ) + ELSE 0 + END, total_read_count = vfs.num_of_reads, avg_read_stall_ms = @@ -917,7 +931,7 @@ OPTION(MAXDOP 1, RECOMPILE);', ISNULL ( vfs.io_stall_read_ms / - (1.0 * NULLIF(vfs.num_of_reads, 0)), + (NULLIF(vfs.num_of_reads, 0)), 0 ) ), @@ -931,6 +945,16 @@ OPTION(MAXDOP 1, RECOMPILE);', ) ELSE 0 END, + total_mb_written = + CASE + WHEN vfs.num_of_bytes_written > 0 + THEN CONVERT + ( + decimal(38, 2), + vfs.num_of_bytes_written / 1048576. + ) + ELSE 0 + END, total_write_count = vfs.num_of_writes, avg_write_stall_ms = @@ -940,10 +964,12 @@ OPTION(MAXDOP 1, RECOMPILE);', ISNULL ( vfs.io_stall_write_ms / - (1.0 * NULLIF(vfs.num_of_writes, 0)), + (NULLIF(vfs.num_of_writes, 0)), 0 ) ), + io_stall_read_ms, + io_stall_write_ms, sample_time = GETDATE() FROM sys.dm_io_virtual_file_stats(NULL, NULL) AS vfs @@ -963,7 +989,7 @@ OPTION(MAXDOP 1, RECOMPILE);', N' WHERE ( - vfs.num_of_reads > 0 + vfs.num_of_reads > 0 OR vfs.num_of_writes > 0 );' ); @@ -983,11 +1009,15 @@ OPTION(MAXDOP 1, RECOMPILE);', database_file_details, file_size_gb, total_gb_read, + total_mb_read, total_read_count, avg_read_stall_ms, total_gb_written, + total_mb_written, total_write_count, avg_write_stall_ms, + io_stall_read_ms, + io_stall_write_ms, sample_time ) EXEC sys.sp_executesql @@ -1102,26 +1132,52 @@ OPTION(MAXDOP 1, RECOMPILE);', fm.database_file_details, fm.file_size_gb, avg_read_stall_ms = - CONVERT - ( - decimal(38, 2), - (fm2.avg_read_stall_ms + fm.avg_read_stall_ms) / 2 - ), + CASE + WHEN (fm2.total_read_count - fm.total_read_count) = 0 + THEN 0.00 + ELSE + CONVERT + ( + decimal(38, 2), + (fm2.io_stall_read_ms - fm.io_stall_read_ms) / + (fm2.total_read_count - fm.total_read_count) + ) + END, avg_write_stall_ms = - CONVERT - ( - decimal(38, 2), - (fm2.avg_write_stall_ms + fm.avg_write_stall_ms) / 2 - ), + CASE + WHEN (fm2.total_write_count - fm.total_write_count) = 0 + THEN 0.00 + ELSE + CONVERT + ( + decimal(38, 2), + (fm2.io_stall_write_ms - fm.io_stall_write_ms) / + (fm2.total_write_count - fm.total_write_count) + ) + END, total_avg_stall = - ( - (fm2.avg_read_stall_ms + fm2.avg_write_stall_ms) + - (fm.avg_read_stall_ms + fm.avg_write_stall_ms) / 2 - ), - total_gb_read = - (fm2.total_gb_read - fm.total_gb_read), - total_gb_written = - (fm2.total_gb_written - fm.total_gb_written), + CASE + WHEN (fm2.total_read_count - fm.total_read_count) + + (fm2.total_write_count - fm.total_write_count) = 0 + THEN 0.00 + ELSE + CONVERT + ( + decimal(38,2), + ( + (fm2.io_stall_read_ms - fm.io_stall_read_ms) + + (fm2.io_stall_write_ms - fm.io_stall_write_ms) + ) / + ( + (fm2.total_read_count - fm.total_read_count) + + (fm2.total_write_count - fm.total_write_count) + ) + ) + END, + total_mb_read = + (fm2.total_mb_read - fm.total_mb_read), + total_mb_written = + (fm2.total_mb_written - fm.total_mb_written), total_read_count = (fm2.total_read_count - fm.total_read_count), total_write_count = @@ -1145,8 +1201,38 @@ OPTION(MAXDOP 1, RECOMPILE);', f.avg_read_stall_ms, f.avg_write_stall_ms, f.total_avg_stall, - f.total_gb_read, - f.total_gb_written, + total_mb_read = + REPLACE + ( + CONVERT + ( + nvarchar(30), + CONVERT + ( + money, + f.total_mb_read + ), + 1 + ), + N'.00', + N'' + ), + total_mb_written = + REPLACE + ( + CONVERT + ( + nvarchar(30), + CONVERT + ( + money, + f.total_mb_written + ), + 1 + ), + N'.00', + N'' + ), total_read_count = REPLACE ( @@ -1182,8 +1268,11 @@ OPTION(MAXDOP 1, RECOMPILE);', sample_seconds = DATEDIFF(SECOND, f.sample_time_o, f.sample_time_t) FROM f - WHERE f.total_read_count > 0 - OR f.total_write_count > 0 + WHERE + ( + f.total_read_count > 0 + OR f.total_write_count > 0 + ) ORDER BY f.total_avg_stall DESC; END @@ -2602,7 +2691,8 @@ OPTION(MAXDOP 1, RECOMPILE);', x.* FROM @file_metrics AS x ORDER BY - x.database_name + x.database_name, + x.sample_time OPTION(RECOMPILE); SELECT