Skip to content

Commit

Permalink
Add PSP demo for SQL Server 2022
Browse files Browse the repository at this point in the history
  • Loading branch information
rgward committed Jan 14, 2022
1 parent db6f1e9 commit fdb613f
Show file tree
Hide file tree
Showing 14 changed files with 174 additions and 0 deletions.
8 changes: 8 additions & 0 deletions demos/sqlserver2022/psp/dbcompat160.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
USE WideWorldImporters;
GO
ALTER DATABASE CURRENT SET COMPATIBILITY_LEVEL = 160;
GO
ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE;
GO
ALTER DATABASE CURRENT SET QUERY_STORE CLEAR;
GO
14 changes: 14 additions & 0 deletions demos/sqlserver2022/psp/dmv_query_stats.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
SELECT TOP 50 query_stats.query_hash AS "Query Hash",
SUM(query_stats.total_worker_time) / SUM(query_stats.execution_count) AS "Avg CPU Time",
MIN(query_stats.statement_text) AS "Statement Text"
FROM
(SELECT QS.*,
SUBSTRING(ST.text, (QS.statement_start_offset/2) + 1,
((CASE statement_end_offset
WHEN -1 THEN DATALENGTH(ST.text)
ELSE QS.statement_end_offset END
- QS.statement_start_offset)/2) + 1) AS statement_text
FROM sys.dm_exec_query_stats AS QS
CROSS APPLY sys.dm_exec_sql_text(QS.sql_handle) as ST) as query_stats
GROUP BY query_stats.query_hash, query_stats.statement_text
ORDER BY [Avg CPU Time] DESC
46 changes: 46 additions & 0 deletions demos/sqlserver2022/psp/populatedata.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
-- Add StockItems to cause a data skew in Suppliers
--
DECLARE @StockItemID int
DECLARE @StockItemName varchar(100)
DECLARE @SupplierID int
SELECT @StockItemID = 228
SET @StockItemName = 'Dallas Cowboys Shirt'+convert(varchar(10), @StockItemID)
SET @SupplierID = 4
DELETE FROM Warehouse.StockItems WHERE StockItemID >= @StockItemID
SET NOCOUNT ON
BEGIN TRANSACTION
WHILE @StockItemID <= 4000000
BEGIN
INSERT INTO Warehouse.StockItems
(StockItemID, StockItemName, SupplierID, UnitPackageID, OuterPackageID, LeadTimeDays,
QuantityPerOuter, IsChillerStock, TaxRate, UnitPrice, TypicalWeightPerUnit, LastEditedBy
)
VALUES (@StockItemID, @StockItemName, @SupplierID, 10, 9, 12, 100, 0, 15.00, 100.00, 0.300, 1)
SET @StockItemID = @StockItemID + 1
SET @StockItemName = 'Dallas Cowboys Shirt'+convert(varchar(10), @StockItemID)
END
COMMIT TRANSACTION
SET NOCOUNT OFF
GO
DECLARE @StockItemID int
DECLARE @StockItemName varchar(100)
DECLARE @SupplierID int
SELECT @StockItemID = 4000001
SET @StockItemName = 'Dallas Cowboys Mug'+convert(varchar(10), @StockItemID)
SET @SupplierID = 5
DELETE FROM Warehouse.StockItems WHERE StockItemID >= @StockItemID
SET NOCOUNT ON
BEGIN TRANSACTION
WHILE @StockItemID <= 8000000
BEGIN
INSERT INTO Warehouse.StockItems
(StockItemID, StockItemName, SupplierID, UnitPackageID, OuterPackageID, LeadTimeDays,
QuantityPerOuter, IsChillerStock, TaxRate, UnitPrice, TypicalWeightPerUnit, LastEditedBy
)
VALUES (@StockItemID, @StockItemName, @SupplierID, 10, 9, 12, 100, 0, 15.00, 100.00, 0.300, 1)
SET @StockItemID = @StockItemID + 1
SET @StockItemName = 'Dallas Cowboys Mug'+convert(varchar(10), @StockItemID)
END
COMMIT TRANSACTION
SET NOCOUNT OFF
GO
12 changes: 12 additions & 0 deletions demos/sqlserver2022/psp/proc.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
USE WideWorldImporters;
GO
CREATE OR ALTER PROCEDURE [Warehouse].[GetStockItemsbySupplier]
@SupplierID int
AS
BEGIN
SELECT StockItemID, SupplierID, StockItemName, TaxRate, LeadTimeDays
FROM Warehouse.StockItems s
WHERE SupplierID = @SupplierID
ORDER BY StockItemName
END;
GO
7 changes: 7 additions & 0 deletions demos/sqlserver2022/psp/query_plan_scan.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- The best plan for this parameter is an index scan
USE WideWorldImporters;
GO
ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE
GO
EXEC Warehouse.GetStockItemsbySupplier 4
GO
5 changes: 5 additions & 0 deletions demos/sqlserver2022/psp/query_plan_seek.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
-- The best plan for this parameter is an index seek
USE WideWorldImporters;
GO
EXEC Warehouse.GetStockItemsbySupplier 2
GO
8 changes: 8 additions & 0 deletions demos/sqlserver2022/psp/query_store_dmvs.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
SELECT * FROM sys.query_store_query_text;
GO
SELECT * FROM sys.query_store_query;
GO
SELECT * FROM sys.query_store_plan;
GO
SELECT * FROM sys.query_store_query_variant;
GO
55 changes: 55 additions & 0 deletions demos/sqlserver2022/psp/readme.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
# Demo steps for Parameter Sensitive Plan Optimization (PSP)

Here are the steps to demonstrate the new PSP optimization feature for SQL Server 2022

## Setup

1. Copy WideWorldImporters from https://github.com/Microsoft/sql-server-samples/releases/download/wide-world-importers-v1.0/WideWorldImporters-Full.bak

2. Install SQL Server 2022 (during private preview I used developer edition)

3. Restore the WideWorldImporters backup. You can edit and use the **restorewwi.sql** script.

4. Load and execute the **populatedata.sql** script to load more data into the Warehouse.StockItems table

5. Rebuild an index associated with the table with **rebuild_index.sql**

6. Create a new procedure to be used for the workload test using **proc.sql**.

7. Edit your servername in sqlsetup.cmd and execute the script. This will ensure the WideWorldImporters database is at dbcompat 150, clear the query store, and set any trace flags needed during private preview.]

8. Edit the scripts workload_index_scan.cmd and workload_index_seek.cmd for your servername.

## Show query plan differences for PSP

1. Using SSMS turn on the Actual Execution Plan option and execute the query in **query_plan_seek.sql**. You will see this executes very fast and uses an Index Seek.

2. In a different query window, using SSMS turn on the Actual Execution Plan option and execute the query in **query_plan_scan.sql**. You will this takes several seconds to run and uses an Index Scan. This script clears procedure cache for the database to simulate plan cache eviction.

3. Run the query in **query_plan_seek.sql** again. You will see it now uses a scan but doesn't seem to run that much slower.

3. Now to see PSP optimization in action, run the script **dbcompat160.sql** to set the dbcompat level to 160. This enables the QP to use PSP optimization.

4. Now repeat the same steps as 1-3 above. When you execute the query in **query_plan_seek.sq**l the 2nd time it should now use an index seek.

5. You can observe different plans for the same query_hash using the scripts **dmv_query_stats.sql** and**query_store_dmvs.sql**.

## Show performance differences using a workload

Even though in the previous section the performance of an individual execution of a query didn't seem to regress because of PSP, what if the query in query_plan_index.sql had to be run my multiple users frequently? This is where having the right plan matters.

Note: if you want to observe the performance differences in perfmon, add counters for batch requests/sec and % Processor time.

1. Run **sqlsetup.cmd as you did in the setup section.**. This wil reset the dbcompat level and clear the query store.

2. Run **workload_index_seek.cmd**. This runs the stored procedure with the same parameter as seen with query_plan_seek.sql Not the overall duration time from ostress. Also if you have setup perfmon, note the high, but reasonable CPU time and the avg batch requests/sec.

3. Run **workload_index_scan.cmd**. This will clear procedure cache to simulate a plan cache eviction and run the same query as in query_plan_scan.sql.

4. Now run **workload_index_seek.cmd** again. You will see quickly it runs past the last duration time. If you look at perfmon you will see almost 100% CPU time with huge drop in batch requests/sec. This is because all the users are running the proc with index scans. You will need to cancel this workload by hitting <Ctrl>+<C> as it can take many minutes to finish.

5. Let's get this workload much faster using PSP optimization. Execute the T-SQL script **dbcompat160.sql** with SSMS.

6. Run through the same sequence as in steps 2-4. You will see now in Step 4 the execution of workload_index_seek.cmd should be the same as the first run and perfmon should show consistent execution.

7. You can observe the same details for query plans using **dmv_query_stats.sql** and **query_store_dmvs.sql**.
2 changes: 2 additions & 0 deletions demos/sqlserver2022/psp/rebuild_index.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
ALTER INDEX FK_Warehouse_StockItems_SupplierID ON Warehouse.StockItems REBUILD;
GO
7 changes: 7 additions & 0 deletions demos/sqlserver2022/psp/restorewwi.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
restore database WideWorldImporters from disk = 'c:\sql_sample_databases\WideWorldImporters-Full.bak' with
move 'WWI_Primary' to 'c:\sql_sample_databases\WideWorldImporters.mdf',
move 'WWI_UserData' to 'c:\sql_sample_databases\WideWorldImporters_UserData.ndf',
move 'WWI_Log' to 'c:\sql_sample_databases\WideWorldImporters.ldf',
move 'WWI_InMemory_Data_1' to 'c:\sql_sample_databases\WideWorldImporters_InMemory_Data_1',
stats=5
go
1 change: 1 addition & 0 deletions demos/sqlserver2022/psp/sqlsetup.cmd
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
.\ostress -S.\sqlserver2022 -E -Q"alter database current set compatibility_level = 150; alter database current set query_store clear;DBCC TRACEON (11091, 12619, -1);" -dWideWorldImporters -q
3 changes: 3 additions & 0 deletions demos/sqlserver2022/psp/workload_index_scan.cmd
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
.\ostress -S.\sqlserver2022 -E -Q"ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE;" -n1 -r1 -q -oworkload_wwi_regress -dWideWorldImporters
.\ostress -S.\sqlserver2022 -E -Q"EXEC Warehouse.GetStockItemsbySupplier 4;" -n1 -r1 -q -oworkload_wwi_regress -dWideWorldImporters

1 change: 1 addition & 0 deletions demos/sqlserver2022/psp/workload_index_seek.cmd
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
.\ostress -S.\sqlserver2022 -E -Q"EXEC Warehouse.GetStockItemsbySupplier 2;" -n25 -r1000 -q -dWideWorldImporters
5 changes: 5 additions & 0 deletions demos/sqlserver2022/readme.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
# SQL Server 2022 demos

psp

Demo for Parameter Sensitive Plan (PSP) optimization

0 comments on commit fdb613f

Please sign in to comment.