Browse Source

Add files via upload

Parikshit 8 năm trước cách đây
mục cha
commit
fd68cdc00a

+ 112 - 0
Automatic tuning/demo-full.sql

@@ -0,0 +1,112 @@
+use wideworldimporters
+go
+
+/********************************************************
+*	SETUP - clear everything
+********************************************************/
+EXEC [dbo].[initialize]
+
+
+/********************************************************
+*	PART I
+*	Plan regression identification.
+********************************************************/
+
+-- 1. Start workload - execute procedure 30 times:
+-- Confirm that execution time is (3 sec total)
+begin
+declare @packagetypeid int = 7;
+exec dbo.report @packagetypeid
+end
+go 30
+
+-- 2. Execute procedure that causes plan regression
+exec dbo.regression
+
+-- 3. Start workload again - verify that is slower.
+-- Execution time should be (8secs in total)
+-- Notice we only ran it 20 times and it was still 50%+ slower
+begin
+declare @packagetypeid int = 7;
+exec dbo.report @packagetypeid
+end
+go 20
+
+-- 4. Find recommendation recommended by database:
+
+SELECT reason, score,
+	JSON_VALUE(state, '$.currentValue') state,
+	JSON_VALUE(state, '$.reason') state_transition_reason,
+    JSON_VALUE(details, '$.implementationDetails.script') script,
+    planForceDetails.*
+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 '$.recommendedPlanId'
+          ) as planForceDetails;
+
+-- Note: User can apply script and force the recommended plan to correct the error.
+-- In part II will be shown better approach - automatic tuning.
+
+/********************************************************
+*	PART II
+*	Automatic tuning
+********************************************************/
+
+/********************************************************
+*	RESET - clear everything
+********************************************************/
+DBCC FREEPROCCACHE;
+ALTER DATABASE current SET QUERY_STORE CLEAR ALL;
+
+-- Enable automatic tuning on the database:
+ALTER DATABASE current
+SET AUTOMATIC_TUNING ( FORCE_LAST_GOOD_PLAN = ON);
+
+-- Verify that actual state on FLGP is ON:
+SELECT name, desired_state_desc, actual_state_desc, reason_desc
+FROM sys.database_automatic_tuning_options;
+
+
+-- 1. Start workload - execute procedure 30 times like in the phase I
+-- Execution should be around 3-4 secs again.
+begin
+declare @packagetypeid int = 7;
+exec dbo.report @packagetypeid
+end
+go 30
+
+-- 2. Execute the procedure that causes plan regression
+exec dbo.regression
+
+-- 3. Start workload again - verify that it is slower.
+-- Execution should be again 50%+ slower with only 20 executions
+begin
+declare @packagetypeid int = 7;
+exec dbo.report @packagetypeid
+end
+go 20
+
+-- 4. Find recommendation that returns query perf regression
+-- and check is it in Verifying state:
+SELECT reason, score,
+	JSON_VALUE(state, '$.currentValue') state,
+	JSON_VALUE(state, '$.reason') state_transition_reason,
+    JSON_VALUE(details, '$.implementationDetails.script') script,
+    planForceDetails.*
+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 '$.recommendedPlanId'
+          ) as planForceDetails;
+	  
+-- 5. Wait until recommendation is applied and start workload again - verify that it is faster.
+-- Execution should be back to normal execution
+begin
+declare @packagetypeid int = 7;
+exec dbo.report @packagetypeid
+end
+go 20
+-- Open query store dialogs in SSMS and show that better plan is forced looking at the Top Resource Consuming Queries Report

+ 28 - 0
Automatic tuning/query_store_waits.sql

@@ -0,0 +1,28 @@
+use wideworldimporters
+go
+dbcc dropcleanbuffers
+go
+exec dbo.report 7
+go
+select * from sys.query_store_wait_stats
+go
+select * from sys.query_store_runtime_stats
+go
+-- Show me which queries waited on PAGEIOLATCH and how much average wait time
+-- was on the latch vs overal duration
+select qt.query_sql_text, qrs.avg_duration, qws.avg_query_wait_time_ms
+from sys.query_store_query_text qt
+join sys.query_store_query qq
+on qt.query_text_id = qq.query_text_id
+join sys.query_store_plan qsp
+on qsp.query_id = qq.query_id
+join sys.query_store_runtime_stats qrs
+on qrs.plan_id = qsp.plan_id
+join sys.query_store_wait_stats qws
+on qws.plan_id = qsp.plan_id
+and qws.wait_category = 6
+go
+select wait_category_desc, count(*), avg(avg_query_wait_time_ms) avg_wait_time_ms
+from sys.query_store_wait_stats
+group by wait_category_desc
+go

+ 8 - 0
Automatic tuning/restore_wwi.sql

@@ -0,0 +1,8 @@
+restore filelistonly from disk = 'c:\temp\wideworldimporters-full.bak'
+go
+restore database wideworldimporters from disk = 'c:\temp\wideworldimporters-full.bak'
+with move 'wwi_primary' to 'c:\temp\wideworldimporters.mdf',
+move 'wwi_userdata' to 'c:\temp\wideworldimporters_userdata.ndf',
+move 'wwi_log' to 'c:\temp\wideworldimporters.ldf',
+move 'wwi_inmemory_data_1' to 'c:\temp\wideworldimporters_inmemory_data_1'
+go

+ 47 - 0
Automatic tuning/setup.sql

@@ -0,0 +1,47 @@
+use wideworldimporters
+go
+DROP procedure [dbo].[initialize]
+go
+CREATE   procedure [dbo].[initialize]
+as begin
+DBCC FREEPROCCACHE;
+ALTER DATABASE current SET QUERY_STORE CLEAR ALL;
+ALTER DATABASE current SET AUTOMATIC_TUNING ( FORCE_LAST_GOOD_PLAN = OFF);
+end
+GO
+
+DROP procedure [dbo].[fix]
+go
+CREATE   procedure [dbo].[fix]
+as begin
+ALTER DATABASE current SET AUTOMATIC_TUNING ( FORCE_LAST_GOOD_PLAN = ON);
+DBCC FREEPROCCACHE;
+ALTER DATABASE current SET QUERY_STORE CLEAR ALL;
+end
+GO
+
+DROP PROCEDURE [dbo].[report]
+go
+CREATE PROCEDURE [dbo].[report] ( @packagetypeid INT )
+AS
+    BEGIN
+
+        SELECT  AVG([UnitPrice] * [Quantity] - [TaxRate])
+        FROM    [Sales].[OrderLines]
+        WHERE   [PackageTypeID] = @packagetypeid;
+
+    END;
+GO
+
+DROP PROCEDURE [dbo].[regression]
+go
+CREATE PROCEDURE [dbo].[regression]
+AS
+    BEGIN
+        DBCC FREEPROCCACHE;
+        BEGIN
+            DECLARE @packagetypeid INT = 1;
+            EXEC [report] @packagetypeid;
+        END;
+    END;
+GO