diff --git a/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/demo-full.sql b/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/demo-full.sql index d8df1f45c1..0fed3f0bd0 100644 --- a/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/demo-full.sql +++ b/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/demo-full.sql @@ -9,7 +9,7 @@ EXEC [dbo].[initialize] * Plan regression identification. ********************************************************/ --- 1. Start workload - execute procedure 30 times: +-- 1. Start workload - execute procedure 30-300 times: begin declare @packagetypeid int = 7; exec dbo.report @packagetypeid @@ -34,15 +34,16 @@ go 20 -- 4. Find recommendation recommended by database: SELECT planForceDetails.query_id, reason, score, - JSON_VALUE(details, '$.implementationDetails.script') script, + JSON_VALUE(details, '$.implementationDetails.script') [correction script], planForceDetails.[new plan_id], planForceDetails.[recommended plan_id] FROM sys.dm_db_tuning_recommendations CROSS APPLY OPENJSON (Details, '$.planForceDetails') WITH ( [query_id] int '$.queryId', [new plan_id] int '$.regressedPlanId', - [recommended plan_id] int '$.forcedPlanId' + [recommended plan_id] int '$.recommendedPlanId' ) as planForceDetails; + -- Note: User can apply script and force the recommended plan to correct the error. <> -- e.g.: exec sp_query_store_force_plan @query_id = 3, @plan_id = 1 @@ -66,7 +67,7 @@ go 20 /******************************************************** * RESET - clear everything ********************************************************/ -EXEC [dbo].[initialize] +EXEC [dbo].[initialize]; -- Enable automatic tuning on the database: ALTER DATABASE current @@ -77,7 +78,7 @@ SELECT name, desired_state_desc, actual_state_desc, reason_desc FROM sys.database_automatic_tuning_options; --- 1. Start workload - execute procedure 20 times like in the phase I +-- 1. Start workload - execute procedure 30-300 times like in the phase I begin declare @packagetypeid int = 7; exec dbo.report @packagetypeid @@ -85,12 +86,12 @@ end go 300 -- 2. Execute the procedure that causes plan regression -exec dbo.regression +exec dbo.regression; -- 3. Start workload again - verify that it is slower. begin declare @packagetypeid int = 7; -exec dbo.report @packagetypeid +exec dbo.report @packagetypeid; end go 20 @@ -105,7 +106,7 @@ FROM sys.dm_db_tuning_recommendations CROSS APPLY OPENJSON (Details, '$.planForceDetails') WITH ( [query_id] int '$.queryId', [new plan_id] int '$.regressedPlanId', - [recommended plan_id] int '$.forcedPlanId' + [recommended plan_id] int '$.recommendedPlanId' ) as planForceDetails; diff --git a/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/setup.sql b/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/setup.sql index 27442fadeb..b1dd01a1da 100644 --- a/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/setup.sql +++ b/samples/features/automatic-tuning/force-last-good-plan/sql-scripts/setup.sql @@ -13,17 +13,18 @@ CREATE NONCLUSTERED COLUMNSTORE INDEX [NCCX_Sales_OrderLines] ON [Sales].[OrderL )WITH (DROP_EXISTING = OFF, COMPRESSION_DELAY = 0) ON [USERDATA] GO -CREATE procedure [dbo].[initialize] +CREATE OR ALTER PROCEDURE [dbo].[initialize] as begin -DBCC FREEPROCCACHE; +ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; ALTER DATABASE current SET QUERY_STORE CLEAR ALL; ALTER DATABASE current SET AUTOMATIC_TUNING ( FORCE_LAST_GOOD_PLAN = OFF); end GO -CREATE procedure [dbo].[report] (@packagetypeid int) + +CREATE OR ALTER PROCEDURE [dbo].[report] (@packagetypeid int) as begin select avg([UnitPrice]*[Quantity]) @@ -34,35 +35,47 @@ end GO -CREATE procedure [dbo].[regression] +CREATE OR ALTER PROCEDURE [dbo].[regression] as begin -DBCC FREEPROCCACHE; +ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; begin declare @packagetypeid int = 1; - exec report @packagetypeid + exec report @packagetypeid; end end GO -CREATE procedure [dbo].[auto_tuning_on] +CREATE OR ALTER PROCEDURE [dbo].[auto_tuning_on] as begin ALTER DATABASE current SET AUTOMATIC_TUNING ( FORCE_LAST_GOOD_PLAN = ON); -DBCC FREEPROCCACHE; +ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; ALTER DATABASE current SET QUERY_STORE CLEAR ALL; end GO -CREATE procedure [dbo].[auto_tuning_off] +CREATE OR ALTER PROCEDURE [dbo].[auto_tuning_off] as begin ALTER DATABASE current SET AUTOMATIC_TUNING ( FORCE_LAST_GOOD_PLAN = OFF); -DBCC FREEPROCCACHE; +ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; ALTER DATABASE current SET QUERY_STORE CLEAR ALL; end -GO \ No newline at end of file +GO + +CREATE EVENT SESSION [APC - plans that are not corrected] ON SERVER + +ADD EVENT qds.automatic_tuning_plan_regression_detection_check_completed( +WHERE ((([is_regression_detected]=(1)) + AND ([is_regression_corrected]=(0))) + AND ([option_id]=(1)))) +ADD TARGET package0.event_file(SET filename=N'plans_that_are_not_corrected') +WITH (STARTUP_STATE=ON); +GO + +ALTER EVENT SESSION [APC - plans that are not corrected] ON SERVER STATE = start; \ No newline at end of file