From 0dde15e015e93d4dbfc7b0d7e6e717ff59c305ff Mon Sep 17 00:00:00 2001 From: Eitan Blumin Date: Tue, 19 Mar 2024 21:06:50 +0200 Subject: [PATCH] adding sp_AnalyzeQueryStatistics and sp_AnalyzeQueryIndex --- Utility Scripts/sp_AnalyzeQueryIndex.sql | 52 +++++++++++++++++++ Utility Scripts/sp_AnalyzeQueryStatistics.sql | 37 +++++++++++++ 2 files changed, 89 insertions(+) create mode 100644 Utility Scripts/sp_AnalyzeQueryIndex.sql create mode 100644 Utility Scripts/sp_AnalyzeQueryStatistics.sql diff --git a/Utility Scripts/sp_AnalyzeQueryIndex.sql b/Utility Scripts/sp_AnalyzeQueryIndex.sql new file mode 100644 index 0000000..9ca7e81 --- /dev/null +++ b/Utility Scripts/sp_AnalyzeQueryIndex.sql @@ -0,0 +1,52 @@ +/* +This procedure, when executed against a problematic SQL query, provides insights into missing indexes that could improve query performance. +Source: https://techcommunity.microsoft.com/t5/azure-database-support-blog/lesson-learned-481-query-performance-analysis-tips/ba-p/4088795 +*/ +CREATE PROCEDURE sp_AnalyzeQueryIndex + @SQLQuery NVARCHAR(MAX) +AS +BEGIN + SET NOCOUNT ON; + + DECLARE @TableNames TABLE ( + SourceSchema NVARCHAR(128), + TableName NVARCHAR(128), + ObjectId INT + ); + + INSERT INTO @TableNames (SourceSchema, TableName, ObjectId) + SELECT DISTINCT + source_schema AS SourceSchema, + source_table AS TableName, + OBJECT_ID(source_schema + '.' + source_table) AS ObjectId + FROM + sys.dm_exec_describe_first_result_set(@SQLQuery, NULL, 1) sp + WHERE sp.error_number IS NULL AND NOT sp.source_table IS NULL + + SELECT + t.TableName, + migs.group_handle, + migs.unique_compiles, + migs.user_seeks, + migs.user_scans, + migs.last_user_seek, + migs.last_user_scan, + mid.statement, + mid.equality_columns, + mid.inequality_columns, + mid.included_columns + FROM + @TableNames AS t + INNER JOIN + sys.dm_db_missing_index_groups mig ON mig.index_handle IN ( + SELECT index_handle + FROM sys.dm_db_missing_index_details + WHERE object_id = t.ObjectId + ) + INNER JOIN + sys.dm_db_missing_index_group_stats migs ON migs.group_handle = mig.index_group_handle + INNER JOIN + sys.dm_db_missing_index_details mid ON mig.index_handle = mid.index_handle + WHERE + mid.database_id = DB_ID(); +END; diff --git a/Utility Scripts/sp_AnalyzeQueryStatistics.sql b/Utility Scripts/sp_AnalyzeQueryStatistics.sql new file mode 100644 index 0000000..72c1a0d --- /dev/null +++ b/Utility Scripts/sp_AnalyzeQueryStatistics.sql @@ -0,0 +1,37 @@ +/* +This procedure is designed to take a SQL query as input, specified through the @SQLQuery parameter, and dissect it to unveil the underlying schema and tables it interacts with. +Source: https://techcommunity.microsoft.com/t5/azure-database-support-blog/lesson-learned-481-query-performance-analysis-tips/ba-p/4088795 +*/ +CREATE PROCEDURE sp_AnalyzeQueryStatistics + @SQLQuery NVARCHAR(MAX) +AS +BEGIN + SET NOCOUNT ON; + + DECLARE @TableNames TABLE ( + SourceSchema NVARCHAR(128), + TableName NVARCHAR(128) + ); + + INSERT INTO @TableNames (SourceSchema, TableName) + SELECT DISTINCT + source_schema AS SourceSchema, + source_table AS TableName + FROM + sys.dm_exec_describe_first_result_set(@SQLQuery, NULL, 1) sp + WHERE sp.error_number IS NULL AND NOT sp.source_table is NULL + + SELECT + t.TableName, + s.name AS StatisticName, + STATS_DATE(s.object_id, s.stats_id) AS LastUpdated, + sp.rows, + sp.rows_sampled, + sp.modification_counter + FROM + @TableNames AS t + INNER JOIN + sys.stats AS s ON s.object_id = OBJECT_ID(QUOTENAME(t.SourceSchema) + '.' + QUOTENAME(t.TableName)) + CROSS APPLY + sys.dm_db_stats_properties(s.object_id, s.stats_id) AS sp; +END;