Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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.
<<Insert T-SQL from the script column here and execute the script>>
-- e.g.: exec sp_query_store_force_plan @query_id = 3, @plan_id = 1
Expand All @@ -66,7 +67,7 @@ go 20
/********************************************************
* RESET - clear everything
********************************************************/
EXEC [dbo].[initialize]
EXEC [dbo].[initialize];

-- Enable automatic tuning on the database:
ALTER DATABASE current
Expand All @@ -77,20 +78,20 @@ 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
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

Expand All @@ -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;


Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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])
Expand All @@ -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
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;