@@ -330,6 +330,28 @@ SET @msg = N'New query_store_runtime_stats columns ' + CASE @new_columns
330
330
END ;
331
331
RAISERROR (@msg, 0 , 1 ) WITH NOWAIT ;
332
332
333
+ /*
334
+ This section determines if Parameter Sensitive Plan Optimization is enabled on SQL Server 2022+.
335
+ */
336
+
337
+ RAISERROR (' Checking for Parameter Sensitive Plan Optimization ' , 0 , 1 ) WITH NOWAIT ;
338
+
339
+ DECLARE @pspo_out BIT ,
340
+ @pspo_enabled BIT ,
341
+ @pspo_sql NVARCHAR (MAX ) = N' SELECT @i_out = CONVERT(bit,dsc.value)
342
+ FROM ' + QUOTENAME (@DatabaseName) + N' .sys.database_scoped_configurations dsc
343
+ WHERE dsc.name = '' PARAMETER_SENSITIVE_PLAN_OPTIMIZATION'' ;' ,
344
+ @pspo_params NVARCHAR (MAX ) = N ' @i_out INT OUTPUT' ;
345
+
346
+ EXEC sys .sp_executesql @pspo_sql, @pspo_params, @i_out = @pspo_out OUTPUT ;
347
+
348
+ SET @pspo_enabled = CASE WHEN @pspo_out = 1 THEN 1 ELSE 0 END ;
349
+
350
+ SET @msg = N ' Parameter Sensitive Plan Optimization ' + CASE @pspo_enabled
351
+ WHEN 0 THEN N ' not enabled, skipping.'
352
+ WHEN 1 THEN N ' enabled, will analyze.'
353
+ END ;
354
+ RAISERROR (@msg, 0 , 1 ) WITH NOWAIT ;
333
355
334
356
/*
335
357
These are the temp tables we use
@@ -1033,10 +1055,33 @@ IF @MinimumExecutionCount IS NOT NULL
1033
1055
1034
1056
-- You care about stored proc names
1035
1057
IF @StoredProcName IS NOT NULL
1036
- BEGIN
1037
- RAISERROR (N ' Setting stored proc filter' , 0 , 1 ) WITH NOWAIT ;
1038
- SET @sql_where + = N ' AND object_name(qsq.object_id, DB_ID(' + QUOTENAME (@DatabaseName, ' '' ' ) + N' )) = @sp_StoredProcName
1039
- ' ;
1058
+ BEGIN
1059
+
1060
+ IF (@pspo_enabled = 1 )
1061
+ BEGIN
1062
+ RAISERROR (N ' Setting stored proc filter, PSPO enabled' , 0 , 1 ) WITH NOWAIT ;
1063
+ /* If PSPO is enabled, the object_id for a variant query would be 0. To include it, we check whether the object_id = 0 query
1064
+ is a variant query, and whether it's parent query belongs to @sp_StoredProcName. */
1065
+ SET @sql_where + = N ' AND (object_name(qsq.object_id, DB_ID(' + QUOTENAME (@DatabaseName, ' '' ' ) + N' )) = @sp_StoredProcName
1066
+ OR (qsq.object_id = 0
1067
+ AND EXISTS(
1068
+ SELECT 1
1069
+ FROM ' + QUOTENAME (@DatabaseName) + N' .sys.query_store_query_variant vr
1070
+ JOIN ' + QUOTENAME (@DatabaseName) + N' .sys.query_store_query pqsq
1071
+ ON pqsq.query_id = vr.parent_query_id
1072
+ WHERE
1073
+ vr.query_variant_query_id = qsq.query_id
1074
+ AND object_name(pqsq.object_id, DB_ID(' + QUOTENAME (@DatabaseName, ' '' ' ) + N' )) = @sp_StoredProcName
1075
+ )
1076
+ ))
1077
+ ' ;
1078
+ END
1079
+ ELSE
1080
+ BEGIN
1081
+ RAISERROR (N ' Setting stored proc filter' , 0 , 1 ) WITH NOWAIT ;
1082
+ SET @sql_where + = N ' AND object_name(qsq.object_id, DB_ID(' + QUOTENAME (@DatabaseName, ' '' ' ) + N' )) = @sp_StoredProcName
1083
+ ' ;
1084
+ END
1040
1085
END ;
1041
1086
1042
1087
-- I will always love you, but hopefully this query will eventually end
@@ -2270,6 +2315,30 @@ EXEC sys.sp_executesql @stmt = @sql_select,
2270
2315
@sp_Top = @Top, @sp_StartDate = @StartDate, @sp_EndDate = @EndDate, @sp_MinimumExecutionCount = @MinimumExecutionCount, @sp_MinDuration = @duration_filter_ms, @sp_StoredProcName = @StoredProcName, @sp_PlanIdFilter = @PlanIdFilter, @sp_QueryIdFilter = @QueryIdFilter;
2271
2316
2272
2317
2318
+ /* If PSPO is enabled, get procedure names for variant queries.*/
2319
+ IF (@pspo_enabled = 1 )
2320
+ BEGIN
2321
+ DECLARE
2322
+ @pspo_names NVARCHAR (MAX ) = ' ' ;
2323
+
2324
+ SET @pspo_names =
2325
+ ' UPDATE wm
2326
+ SET
2327
+ wm.proc_or_function_name =
2328
+ QUOTENAME(object_schema_name(qsq.object_id, DB_ID(' + QUOTENAME (@DatabaseName, ' '' ' ) + N ' ))) + '' .'' +
2329
+ QUOTENAME(object_name(qsq.object_id, DB_ID(' + QUOTENAME (@DatabaseName, ' '' ' ) + N' )))
2330
+ FROM #working_metrics wm
2331
+ JOIN ' + QUOTENAME (@DatabaseName) + N' .sys.query_store_query_variant AS vr
2332
+ ON vr.query_variant_query_id = wm.query_id
2333
+ JOIN ' + QUOTENAME (@DatabaseName) + N' .sys.query_store_query AS qsq
2334
+ ON qsq.query_id = vr.parent_query_id
2335
+ AND qsq.object_id > 0
2336
+ WHERE
2337
+ wm.proc_or_function_name IS NULL;'
2338
+
2339
+ EXEC sys .sp_executesql @pspo_names;
2340
+ END ;
2341
+
2273
2342
2274
2343
/* This just helps us classify our queries*/
2275
2344
UPDATE #working_metrics
0 commit comments