diff --git a/SqlWatch.Monitor/Project.SqlWatch.Database/Scripts/Pre-Deployment/SetDacVersion.sql b/SqlWatch.Monitor/Project.SqlWatch.Database/Scripts/Pre-Deployment/SetDacVersion.sql index 63064d9c..827cd3fc 100644 --- a/SqlWatch.Monitor/Project.SqlWatch.Database/Scripts/Pre-Deployment/SetDacVersion.sql +++ b/SqlWatch.Monitor/Project.SqlWatch.Database/Scripts/Pre-Deployment/SetDacVersion.sql @@ -1,4 +1,4 @@ -- Generated by MsBuild Step - DO NOT EDIT :setvar DacVersion " - 4.1.0.42000 + 4.1.0.24109 " diff --git a/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_internal_get_query_plans.sql b/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_internal_get_query_plans.sql index 0b130ecb..04dd081b 100644 --- a/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_internal_get_query_plans.sql +++ b/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_internal_get_query_plans.sql @@ -33,7 +33,7 @@ AS with cte_plans as ( select - RN = ROW_NUMBER() over (partition by ph.plan_handle, qs.query_plan_hash order by (select null)) + RN_HANDLE = ROW_NUMBER() over (partition by ph.plan_handle, qs.query_plan_hash order by (select null)) , ph.[plan_handle] , qs.[sql_handle] , query_hash = qs.query_hash @@ -70,7 +70,8 @@ AS ) select - p.RN + p.RN_HANDLE + , RN_HASH = ROW_NUMBER() over (partition by p.sql_instance, query_plan_hash order by (select null)) , p.[plan_handle] , p.[sql_handle] , p.query_hash @@ -95,7 +96,9 @@ AS and mp.[procedure_name] = p.[procedure_name] collate database_default and mp.sqlwatch_database_id = mdb.sqlwatch_database_id; - create unique clustered index idx_tmp_plans on #plans ([plan_handle], [sql_handle], [query_hash], [query_plan_hash], [sql_instance]); + create unique clustered index idx_tmp_plans on #plans ([plan_handle], [sql_handle], [query_hash] + , [query_plan_hash], [sql_instance], sqlwatch_procedure_id, sqlwatch_database_id, RN_HANDLE, RN_HASH + , statement_start_offset, statement_end_offset); merge [dbo].[sqlwatch_meta_query_plan] as target using ( @@ -156,16 +159,15 @@ AS merge dbo.[sqlwatch_meta_query_plan_hash] as target using ( - select distinct + select [sql_instance] , [query_plan_hash] , [statement] , [query_plan] - , [statement_start_offset] - , [statement_end_offset] - , RN + --, [statement_start_offset] + --, [statement_end_offset] from #plans - where RN = 1 + where RN_HASH = 1 and [query_plan_hash] not in (0x000,0x00) )as source @@ -184,8 +186,8 @@ AS , [query_plan_for_query_plan_hash] , [date_first_seen] , [date_last_seen] - , [statement_start_offset] - , [statement_end_offset] + --, [statement_start_offset] + --, [statement_end_offset] ) values ( source.[sql_instance] @@ -194,7 +196,7 @@ AS , source.query_plan , @date_now , @date_now - , source.[statement_start_offset] - , source.[statement_end_offset] + --, source.[statement_start_offset] + --, source.[statement_end_offset] ) ; \ No newline at end of file diff --git a/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_logger_query_stats.sql b/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_logger_query_stats.sql index f914ba69..deeeee65 100644 --- a/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_logger_query_stats.sql +++ b/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Procedures/usp_sqlwatch_logger_query_stats.sql @@ -8,7 +8,10 @@ begin declare @snapshot_type_id smallint = 28, @snapshot_time datetime2(0), @date_snapshot_previous datetime2(0), - @sql_instance varchar(32) = [dbo].[ufn_sqlwatch_get_servername](); + @sql_instance varchar(32) = [dbo].[ufn_sqlwatch_get_servername](), + @sql_version smallint = [dbo].[ufn_sqlwatch_get_sql_version](), + @sql nvarchar(max) = '', + @sql_params nvarchar(max) = ''; select @date_snapshot_previous = max([snapshot_time]) from [dbo].[sqlwatch_logger_snapshot_header] (nolock) --so we dont get blocked by central repository. this is safe at this point. @@ -36,10 +39,6 @@ begin create unique clustered index icx_tmp_query_stats_prev on #t ([sql_instance],plan_handle,statement_start_offset, statement_end_offset, [creation_time]); - exec [dbo].[usp_sqlwatch_internal_insert_header] - @snapshot_time_new = @snapshot_time OUTPUT, - @snapshot_type_id = @snapshot_type_id - select qs.* into #s from sys.dm_exec_query_stats qs @@ -68,7 +67,13 @@ begin @sql_instance = @sql_instance ; + exec [dbo].[usp_sqlwatch_internal_insert_header] + @snapshot_time_new = @snapshot_time OUTPUT, + @snapshot_type_id = @snapshot_type_id; + + set @sql_params = '@snapshot_type_id smallint, @snapshot_time datetime2(0),@sql_instance varchar(32)'; + set @sql = ' insert into [dbo].[sqlwatch_logger_perf_query_stats] ( [sql_instance] , [snapshot_time] , @@ -181,30 +186,57 @@ begin ,qs.last_rows ,qs.min_rows ,qs.max_rows - ,qs.total_dop - ,qs.last_dop - ,qs.min_dop - ,qs.max_dop - ,qs.total_grant_kb - ,qs.last_grant_kb - ,qs.min_grant_kb - ,qs.max_grant_kb - ,qs.total_used_grant_kb - ,qs.last_used_grant_kb - ,qs.min_used_grant_kb - ,qs.max_used_grant_kb - ,qs.total_ideal_grant_kb - ,qs.last_ideal_grant_kb - ,qs.min_ideal_grant_kb - ,qs.max_ideal_grant_kb - ,qs.total_reserved_threads - ,qs.last_reserved_threads - ,qs.min_reserved_threads - ,qs.max_reserved_threads - ,qs.total_used_threads - ,qs.last_used_threads - ,qs.min_used_threads - ,qs.max_used_threads + ' + case when @sql_version >= 2016 then ' + ,qs.total_dop + ,qs.last_dop + ,qs.min_dop + ,qs.max_dop + ,qs.total_grant_kb + ,qs.last_grant_kb + ,qs.min_grant_kb + ,qs.max_grant_kb + ,qs.total_used_grant_kb + ,qs.last_used_grant_kb + ,qs.min_used_grant_kb + ,qs.max_used_grant_kb + ,qs.total_ideal_grant_kb + ,qs.last_ideal_grant_kb + ,qs.min_ideal_grant_kb + ,qs.max_ideal_grant_kb + ,qs.total_reserved_threads + ,qs.last_reserved_threads + ,qs.min_reserved_threads + ,qs.max_reserved_threads + ,qs.total_used_threads + ,qs.last_used_threads + ,qs.min_used_threads + ,qs.max_used_threads' + else ' + ,total_dop=null + ,last_dop=null + ,min_dop=null + ,max_dop=null + ,total_grant_kb=null + ,last_grant_kb=null + ,min_grant_kb=null + ,max_grant_kb=null + ,total_used_grant_kb=null + ,last_used_grant_kb=null + ,min_used_grant_kb=null + ,max_used_grant_kb=null + ,total_ideal_grant_kb=null + ,last_ideal_grant_kb=null + ,min_ideal_grant_kb=null + ,max_ideal_grant_kb=null + ,total_reserved_threads=null + ,last_reserved_threads=null + ,min_reserved_threads=null + ,max_reserved_threads=null + ,total_used_threads=null + ,last_used_threads=null + ,min_used_threads=null + ,max_used_threads=null' + end + ' , delta_worker_time = [dbo].[ufn_sqlwatch_get_delta_value](prev.total_worker_time, qs.total_worker_time) , delta_physical_reads = [dbo].[ufn_sqlwatch_get_delta_value](prev.total_physical_reads, qs.total_physical_reads) @@ -221,4 +253,11 @@ begin and prev.statement_start_offset = qs.statement_start_offset and prev.statement_end_offset = qs.statement_end_offset and prev.[creation_time] = qs.creation_time; + '; + + exec sp_executesql @sql + , @sql_params + , @snapshot_time = @snapshot_time + , @snapshot_type_id = @snapshot_type_id + , @sql_instance = @sql_instance; end; \ No newline at end of file diff --git a/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Tables/sqlwatch_meta_query_plan_hash.sql b/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Tables/sqlwatch_meta_query_plan_hash.sql index d4277e3a..6ae69a13 100644 --- a/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Tables/sqlwatch_meta_query_plan_hash.sql +++ b/SqlWatch.Monitor/Project.SqlWatch.Database/dbo/Tables/sqlwatch_meta_query_plan_hash.sql @@ -3,20 +3,28 @@ [sql_instance] varchar(32) not null, [query_plan_hash] varbinary(8) not null, --constraint df_sqlwatch_meta_query_plan_query_plan_hash default 0x00000000, [query_plan_for_query_plan_hash] nvarchar(max) null, - [statement_start_offset] int not null, - [statement_end_offset] int not null, + --< to be removed in next Major + [statement_start_offset] int null, + [statement_end_offset] int null, + --to be removed in next Major > [statement_for_query_plan_hash] varchar(max) null, [date_first_seen] datetime, [date_last_seen] datetime, constraint pk_sqlwatch_meta_plan_handle primary key clustered ( - sql_instance, [query_plan_hash], [statement_start_offset], [statement_end_offset] + sql_instance, [query_plan_hash] --, [statement_start_offset], [statement_end_offset] ), + /* TODO TO DO THIS NEEDS PERIOD RETENTION TO REMOVE ANY PLAN HASHSES THAT DO NOT HAVE PARENT PLAN HANDLE */ --cannot have a constraint to plan_handle as we are storing query plans at the hash level. --multiple handles across different databases may have the same hash. --constraint fk_sqlwatch_meta_plan_handle -- foreign key (sql_instance, [plan_handle], [query_plan_hash], [statement_start_offset], [statement_end_offset]) -- references [dbo].[sqlwatch_meta_query_plan_handle] (sql_instance, [plan_handle], [query_plan_hash], [statement_start_offset], [statement_end_offset]) -- on delete cascade + + constraint fk_sqlwatch_meta_query_plan_hash_sql_instance + foreign key (sql_instance) + references dbo.sqlwatch_meta_server (servername) + on delete cascade ); \ No newline at end of file