Skip to content

Commit b401b6b

Browse files
committed
Added new demos for SQL Server 2022
1 parent 608aa83 commit b401b6b

27 files changed

+297
-0
lines changed
Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
sp_configure 'show advanced', 1;
2+
go
3+
reconfigure;
4+
go
5+
sp_configure 'max degree of parallelism', 0;
6+
go
7+
reconfigure;
8+
go
Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
SELECT qsp.query_plan_hash, avg_duration/1000 as avg_duration_ms,
2+
avg_cpu_time/1000 as avg_cpu_ms, last_dop, min_dop, max_dop
3+
FROM sys.query_store_runtime_stats qsrs
4+
JOIN sys.query_store_plan qsp
5+
ON qsrs.plan_id = qsp.plan_id
6+
and qsp.query_plan_hash = CONVERT(varbinary(8), cast(4128150668158729174 as bigint))
7+
ORDER by qsrs.last_execution_time;
8+
GO
Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,15 @@
1+
USE WideWorldImporters
2+
GO
3+
-- Make sure QS is on and set runtime collection lower than default
4+
ALTER DATABASE WideWorldImporters SET QUERY_STORE = ON
5+
GO
6+
ALTER DATABASE WideWorldImporters SET QUERY_STORE (OPERATION_MODE = READ_WRITE, DATA_FLUSH_INTERVAL_SECONDS = 60, INTERVAL_LENGTH_MINUTES = 1, QUERY_CAPTURE_MODE = ALL)
7+
GO
8+
ALTER DATABASE WideWorldImporters SET QUERY_STORE CLEAR ALL
9+
GO
10+
-- Required as of CTP 2.0
11+
ALTER DATABASE SCOPED CONFIGURATION SET DOP_FEEDBACK = ON
12+
GO
13+
-- Clear proc cache to start with new plans
14+
ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE
15+
GO
Lines changed: 20 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,20 @@
1+
--Setup XE capture
2+
IF EXISTS (SELECT * FROM sys.server_event_sessions WHERE name = 'DOPFeedback')
3+
DROP EVENT SESSION [DOPFeedback] ON SERVER;
4+
GO
5+
CREATE EVENT SESSION [DOPFeedback] ON SERVER
6+
ADD EVENT sqlserver.dop_feedback_eligible_query(
7+
ACTION(sqlserver.query_hash_signed,sqlserver.query_plan_hash_signed,sqlserver.sql_text)),
8+
ADD EVENT sqlserver.dop_feedback_provided(
9+
ACTION(sqlserver.query_hash_signed,sqlserver.query_plan_hash_signed,sqlserver.sql_text)),
10+
ADD EVENT sqlserver.dop_feedback_validation(
11+
ACTION(sqlserver.query_hash_signed,sqlserver.query_plan_hash_signed,sqlserver.sql_text)),
12+
ADD EVENT sqlserver.dop_feedback_reverted(
13+
ACTION(sqlserver.query_hash_signed,sqlserver.query_plan_hash_signed,sqlserver.sql_text))
14+
WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=NO_EVENT_LOSS,MAX_DISPATCH_LATENCY=1 SECONDS,MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF)
15+
GO
16+
17+
-- Start XE
18+
ALTER EVENT SESSION [DOPFeedback] ON SERVER
19+
STATE = START;
20+
GO
Binary file not shown.
Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,26 @@
1+
USE WideWorldImporters;
2+
GO
3+
-- Add StockItems to cause a data skew in Suppliers
4+
--
5+
DECLARE @StockItemID int
6+
DECLARE @StockItemName varchar(100)
7+
DECLARE @SupplierID int
8+
SELECT @StockItemID = 228
9+
SET @StockItemName = 'Dallas Cowboys Shirt'+convert(varchar(10), @StockItemID)
10+
SET @SupplierID = 4
11+
DELETE FROM Warehouse.StockItems WHERE StockItemID >= @StockItemID
12+
SET NOCOUNT ON
13+
BEGIN TRANSACTION
14+
WHILE @StockItemID <= 20000000
15+
BEGIN
16+
INSERT INTO Warehouse.StockItems
17+
(StockItemID, StockItemName, SupplierID, UnitPackageID, OuterPackageID, LeadTimeDays,
18+
QuantityPerOuter, IsChillerStock, TaxRate, UnitPrice, TypicalWeightPerUnit, LastEditedBy
19+
)
20+
VALUES (@StockItemID, @StockItemName, @SupplierID, 10, 9, 12, 100, 0, 15.00, 100.00, 0.300, 1)
21+
SET @StockItemID = @StockItemID + 1
22+
SET @StockItemName = 'Dallas Cowboys Shirt'+convert(varchar(10), @StockItemID)
23+
END
24+
COMMIT TRANSACTION
25+
SET NOCOUNT OFF
26+
GO
Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,11 @@
1+
USE WideWorldImporters;
2+
GO
3+
CREATE OR ALTER PROCEDURE [Warehouse].[GetStockItemsbySupplier] @SupplierID int
4+
AS
5+
BEGIN
6+
SELECT StockItemID, SupplierID, StockItemName, TaxRate, LeadTimeDays
7+
FROM Warehouse.StockItems s
8+
WHERE SupplierID = @SupplierID
9+
ORDER BY StockItemName
10+
END;
11+
GO
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
# DOP Feedback in SQL Server 2022
2+
3+
This demo will show you how to see how to get consistent performance with less CPU resources for queries that require parallel operators
4+
5+
## Pre-requisites
6+
7+
- VM or computer with 8 CPUs and at least 24Gb RAM
8+
- SQL Server 2022 CTP 2.0
9+
10+
## Steps
11+
12+
1. Execute configmaxdop.sql
13+
2. Copy the WideWorldImporters sample database from https://github.com/Microsoft/sql-server-samples/releases/download/wide-world-importers-v1.0/WideWorldImporters-Full.bak to a local directory (The restore script assumes c:\sql_sample_databases)
14+
3. Edit the restorewwi.sql script for the correct paths for the backup and where data and log files should go.
15+
4. Execute the script restorewwi.sql
16+
5. Extend the database by executing populatedata.sql. This will take ~13mins to execute. Because of the large transaction the log will grow to ~30Gb and the user FG will grow to about ~6.5Gb
17+
6. Execute dopfeedback.sql to set QDS settings and db setting for DOP feeback (required for CTP 2.0)
18+
7. Execute proc.sql to create a stored procedure
19+
8. Execute dopexec.sql to create an XEvent session.
20+
9. Use SSMS to Watch the XE session to see Live Data
21+
10. Run workload_index_scan_users.cmd
22+
11. Observe the XEvent data. It will take about 10mins to see XXXX event which means the final DOP setting to achieve stability.
23+
12. Cancel the workload from the cmd script
24+
13. Run dop_query_stats.sql to see the changes in DOP and resulting stats. Not the small decrease in avg duration and decrease in needed CPU
25+
14. Use Top Resource Consuming Queries report and look at Avg Duration and Avg CPU to see the steady decrease until stable.
Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
ALTER INDEX FK_Warehouse_StockItems_SupplierID ON Warehouse.StockItems REBUILD;
2+
GO
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
restore database WideWorldImporters from disk = 'c:\sql_sample_databases\WideWorldImporters-Full.bak' with
2+
move 'WWI_Primary' to 'c:\sql_sample_databases\WideWorldImporters.mdf',
3+
move 'WWI_UserData' to 'c:\sql_sample_databases\WideWorldImporters_UserData.ndf',
4+
move 'WWI_Log' to 'c:\sql_sample_databases\WideWorldImporters.ldf',
5+
move 'WWI_InMemory_Data_1' to 'c:\sql_sample_databases\WideWorldImporters_InMemory_Data_1',
6+
stats=5
7+
go
Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
.\ostress -E -Q"EXEC Warehouse.GetStockItemsbySupplier 4;" -n1 -r200 -q -oworkload_wwi_regress -dWideWorldImporters
2+
Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
USE WideWorldImporters;
2+
GO
3+
ALTER DATABASE CURRENT SET COMPATIBILITY_LEVEL = 160;
4+
GO
5+
ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE;
6+
GO
7+
ALTER DATABASE CURRENT SET QUERY_STORE CLEAR;
8+
GO
1.33 MB
Binary file not shown.
Lines changed: 48 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,48 @@
1+
USE WideWorldImporters;
2+
GO
3+
-- Add StockItems to cause a data skew in Suppliers
4+
--
5+
DECLARE @StockItemID int
6+
DECLARE @StockItemName varchar(100)
7+
DECLARE @SupplierID int
8+
SELECT @StockItemID = 228
9+
SET @StockItemName = 'Dallas Cowboys Shirt'+convert(varchar(10), @StockItemID)
10+
SET @SupplierID = 4
11+
DELETE FROM Warehouse.StockItems WHERE StockItemID >= @StockItemID
12+
SET NOCOUNT ON
13+
BEGIN TRANSACTION
14+
WHILE @StockItemID <= 4000000
15+
BEGIN
16+
INSERT INTO Warehouse.StockItems
17+
(StockItemID, StockItemName, SupplierID, UnitPackageID, OuterPackageID, LeadTimeDays,
18+
QuantityPerOuter, IsChillerStock, TaxRate, UnitPrice, TypicalWeightPerUnit, LastEditedBy
19+
)
20+
VALUES (@StockItemID, @StockItemName, @SupplierID, 10, 9, 12, 100, 0, 15.00, 100.00, 0.300, 1)
21+
SET @StockItemID = @StockItemID + 1
22+
SET @StockItemName = 'Dallas Cowboys Shirt'+convert(varchar(10), @StockItemID)
23+
END
24+
COMMIT TRANSACTION
25+
SET NOCOUNT OFF
26+
GO
27+
DECLARE @StockItemID int
28+
DECLARE @StockItemName varchar(100)
29+
DECLARE @SupplierID int
30+
SELECT @StockItemID = 4000001
31+
SET @StockItemName = 'Dallas Cowboys Mug'+convert(varchar(10), @StockItemID)
32+
SET @SupplierID = 5
33+
DELETE FROM Warehouse.StockItems WHERE StockItemID >= @StockItemID
34+
SET NOCOUNT ON
35+
BEGIN TRANSACTION
36+
WHILE @StockItemID <= 8000000
37+
BEGIN
38+
INSERT INTO Warehouse.StockItems
39+
(StockItemID, StockItemName, SupplierID, UnitPackageID, OuterPackageID, LeadTimeDays,
40+
QuantityPerOuter, IsChillerStock, TaxRate, UnitPrice, TypicalWeightPerUnit, LastEditedBy
41+
)
42+
VALUES (@StockItemID, @StockItemName, @SupplierID, 10, 9, 12, 100, 0, 15.00, 100.00, 0.300, 1)
43+
SET @StockItemID = @StockItemID + 1
44+
SET @StockItemName = 'Dallas Cowboys Mug'+convert(varchar(10), @StockItemID)
45+
END
46+
COMMIT TRANSACTION
47+
SET NOCOUNT OFF
48+
GO

demos/sqlserver2022/IQP/psp/proc.sql

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,11 @@
1+
USE WideWorldImporters;
2+
GO
3+
CREATE OR ALTER PROCEDURE [Warehouse].[GetStockItemsbySupplier] @SupplierID int
4+
AS
5+
BEGIN
6+
SELECT StockItemID, SupplierID, StockItemName, TaxRate, LeadTimeDays
7+
FROM Warehouse.StockItems s
8+
WHERE SupplierID = @SupplierID
9+
ORDER BY StockItemName
10+
END;
11+
GO
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
-- The best plan for this parameter is an index scan
2+
USE WideWorldImporters;
3+
GO
4+
ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE
5+
GO
6+
EXEC Warehouse.GetStockItemsbySupplier 4;
7+
GO
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
-- The best plan for this parameter is an index seek
2+
SET STATISTICS TIME ON;
3+
GO
4+
USE WideWorldImporters;
5+
GO
6+
EXEC Warehouse.GetStockItemsbySupplier 2
7+
GO
Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
SELECT * FROM sys.query_store_query_text;
2+
GO
3+
SELECT * FROM sys.query_store_query;
4+
GO
5+
SELECT * FROM sys.query_store_plan;
6+
GO
7+
SELECT * FROM sys.query_store_query_variant;
8+
GO

demos/sqlserver2022/IQP/psp/readme.md

Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
# Parameter Sensitive Plan Optimization (PSP) in SQL Server 2022
2+
3+
Here are the steps to demonstrate the new PSP optimization feature for SQL Server 2022
4+
5+
## Prerequisites
6+
7+
- VM with at least 4 CPUs and X Gb RAM
8+
- SQL Server 2022 CTP 2.0
9+
- SQL Server Management Studio (SSMS) Version 19 Preview
10+
- Download ostress.exe from https://www.microsoft.com/en-us/download/details.aspx?id=103126
11+
12+
Follow these steps to demonstrate Parameter Sensitive Plan (PSP) optimization
13+
14+
## Setup the demo
15+
16+
1. Copy WideWorldImporters from https://github.com/Microsoft/sql-server-samples/releases/download/wide-world-importers-v1.0/WideWorldImporters-Full.bak (the restore script assumes c:\sql_sample_databases)
17+
2. Restore the WideWorldImporters backup. You can edit and use the **restorewwi.sql** script.
18+
3. Load and execute the **populatedata.sql** script to load more data into the Warehouse.StockItems table. This script will take 5 mins to run
19+
4. Rebuild an index associated with the table with **rebuild_index.sql**
20+
5. Create a new procedure to be used for the workload test using **proc.sql**.
21+
6. Edit your servername in sqlsetup.cmd and execute the script. This will ensure the WideWorldImporters database is at dbcompat 150 and clear the query store.
22+
23+
## See a PSP problem for a single query execution.
24+
25+
7. Set the actual execution plan option in SSMS. Run query_plan_seek.sql in a query window in SSMS. Note the query time is fast and the values from SET STATISTICS TIME is around 20ms. Note the query plan uses an Index Seek.
26+
8. In a different query window set the actual execution option in SSMS. Run query_plan_scan.sql in a query windows in SSMS. Note the query plan uses an Clustered Index Scan and parallelism.
27+
9. Now go back and run query_plan_seek.sql again. Note the timing from SET STATISTICS IO is now ~250ms. Ten times slower but a single execution seems fast.
28+
29+
## See a workload problem for PSP
30+
31+
10. Setup perfmon to catpure % processor time and batch requests/second
32+
11. Edit the scripts workload_index_scan.cmd and workload_index_seek.cmd for your servername.
33+
12. Put ostress.exe in your path or copy it to the local directory. It is installed by default in C:\Program Files\Microsoft Corporation\RMLUtils
34+
13. Run workload_index_seek.cmd. This should complete in a few seconds. Observe perfmon counters.
35+
14. Run workload_index_scan.cmd. This should take longer but now locks into cache a plan for a scan.
36+
15. Run workload_index_seek.cmd again. Observe perfmon counters. Notice much higher CPU and much lower batch requests/sec.
37+
16. Hit <Ctrl>+<C> in the command window for workload_index_seek.cmd as it can take minutes to complete.
38+
17. Use the query suppliercount.sql to see the skew in supplierID values in the table. This explains why "one size does not fit all" for the stored procedure based on parameter values.
39+
40+
## Solve the problem in SQL Server 2022
41+
42+
17. Let's get this workload much faster using PSP optimization. Execute the T-SQL script **dbcompat160.sql** with SSMS.
43+
18. Run workload_index_seek.cmd again. Should finish in a few seconds.
44+
19. Run workload_index_scan.cmd again.
45+
20. Run workload_index_seek.cmd again and see that it now finishs again in a few seconds. Observe perfmon counters and see consistent performance.
46+
21. Run Top Resource Consuming Queries report and see that there are two plans for the same stored procedure
47+
22. It looks like are "two" queries but these are two query "variants". Use the script query_store_dmvs.sql to see the details.
Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
ALTER INDEX FK_Warehouse_StockItems_SupplierID ON Warehouse.StockItems REBUILD;
2+
GO
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
restore database WideWorldImporters from disk = 'c:\sql_sample_databases\WideWorldImporters-Full.bak' with
2+
move 'WWI_Primary' to 'c:\sql_sample_databases\WideWorldImporters.mdf',
3+
move 'WWI_UserData' to 'c:\sql_sample_databases\WideWorldImporters_UserData.ndf',
4+
move 'WWI_Log' to 'c:\sql_sample_databases\WideWorldImporters.ldf',
5+
move 'WWI_InMemory_Data_1' to 'c:\sql_sample_databases\WideWorldImporters_InMemory_Data_1',
6+
stats=5
7+
go
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
.\ostress -E -Q"alter database current set compatibility_level = 150; alter database current set query_store clear;DBCC TRACEON (11091, 12619, -1);" -dWideWorldImporters -q
Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,6 @@
1+
USE WideWorldImporters;
2+
GO
3+
SELECT SupplierID, count(*) as supplier_count
4+
FROM Warehouse.StockItems
5+
GROUP BY SupplierID;
6+
GO
Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
.\ostress -E -Q"ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE;" -n1 -r1 -q -oworkload_wwi_regress -dWideWorldImporters
2+
.\ostress -E -Q"EXEC Warehouse.GetStockItemsbySupplier 4;" -n1 -r1 -q -oworkload_wwi_regress -dWideWorldImporters
3+
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
.\ostress -E -Q"EXEC Warehouse.GetStockItemsbySupplier 2;" -n25 -r1000 -q -dWideWorldImporters

demos/sqlserver2022/IQP/readme.md

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,11 @@
1+
# SQL Server 2022 IQP demos
2+
3+
These are demos to be showcase new IQP features in SQL Server 2022.
4+
5+
*psp*
6+
7+
Demo for Parameter Sensitive Plan (PSP) optimization
8+
9+
*dopfeedback*
10+
11+
Demo for Degree of Parallelism feedback

demos/sqlserver2022/readme.md

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1 +1,7 @@
11
# SQL Server 2022 demos
2+
3+
These are demos to be showcase new features in SQL Server 2022.
4+
5+
*IQP*
6+
7+
Demos for the nextgen of Intelligent Query Processing

0 commit comments

Comments
 (0)