|
|
@@ -36,6 +36,9 @@ Queries may spill to disk or take too much memory based on poor cardinality esti
|
|
|
2. Setup the database to ensure the latest database compatibility level is set, by running the commands below in the query window:
|
|
|
|
|
|
```sql
|
|
|
+ USE master;
|
|
|
+ GO
|
|
|
+
|
|
|
ALTER DATABASE WideWorldImportersDW
|
|
|
SET COMPATIBILITY_LEVEL = 150;
|
|
|
GO
|
|
|
@@ -108,4 +111,90 @@ The legacy behavior mandates that a statement that references a TV is compiled a
|
|
|
|
|
|
Starting with SQL Server 2019, the behavior is that the compilation of a statement that references a TV that doesn’t exist is deferred until the first execution of the statement. This means that SQL Server estimates more accurately and produces optimized query plans based on the actual number of rows in the TV in its first execution.
|
|
|
|
|
|
-1.
|
|
|
+1. Open SSMS and connect to the SQL Server 2019 instance (default instance). Click on **New Query** or press CTRL+N.
|
|
|
+
|
|
|
+ 
|
|
|
+
|
|
|
+2. Setup the database to ensure the database compatibility level of SQL Server 2017 is set, by running the commands below in the query window:
|
|
|
+
|
|
|
+ > **Note:**
|
|
|
+ > This ensures the database engine behavior related to Table Variables is mapped to a version lower than SQL Server 2019.
|
|
|
+
|
|
|
+ ```sql
|
|
|
+ USE master;
|
|
|
+ GO
|
|
|
+
|
|
|
+ ALTER DATABASE [tpch10g-btree]
|
|
|
+ SET COMPATIBILITY_LEVEL = 140;
|
|
|
+ GO
|
|
|
+ ```
|
|
|
+
|
|
|
+4. For the next steps, looking at the query execution plan is needed. Click on **Include Actual Plan** or press CTRL+M.
|
|
|
+
|
|
|
+ 
|
|
|
+
|
|
|
+5. Execute the command below in the query window:
|
|
|
+
|
|
|
+ > **Note:**
|
|
|
+ > This should take between 1 and 5 minutes.
|
|
|
+
|
|
|
+ ```sql
|
|
|
+ USE [tpch10g-btree];
|
|
|
+ GO
|
|
|
+
|
|
|
+ DECLARE @LINEITEMS TABLE
|
|
|
+ (
|
|
|
+ L_OrderKey INT NOT NULL,
|
|
|
+ L_Quantity INT NOT NULL
|
|
|
+ );
|
|
|
+
|
|
|
+ INSERT @LINEITEMS
|
|
|
+ SELECT TOP 750000 L_OrderKey, L_Quantity
|
|
|
+ FROM dbo.lineitem
|
|
|
+ WHERE L_Quantity = 43;
|
|
|
+
|
|
|
+ SELECT O_OrderKey, O_CustKey, O_OrderStatus, L_QUANTITY
|
|
|
+ FROM ORDERS, @LINEITEMS
|
|
|
+ WHERE O_ORDERKEY = L_ORDERKEY
|
|
|
+ AND O_OrderStatus = 'O';
|
|
|
+ GO
|
|
|
+ ```
|
|
|
+
|
|
|
+6. Observe the shape of the query execution plan, that it is a serial plan, and that Nested Loops Joins were chosen given the estimated low number of rows.
|
|
|
+
|
|
|
+7. Click on the **Table Scan** operator in the query execution plan, and hover your mouse over the operator. Observe:
|
|
|
+ - The ***Actual Number of Rows*** is 750000.
|
|
|
+ - The ***Estimated Number of Rows*** is 1.
|
|
|
+ This indicates the legacy behavior of misusing a TV, with the huge estimation skew.
|
|
|
+
|
|
|
+ 
|
|
|
+
|
|
|
+
|
|
|
+8. Setup the database to ensure the latest database compatibility level is set, by running the commands below in the query window:
|
|
|
+
|
|
|
+ > **Note:**
|
|
|
+ > This ensures the database engine behavior related to Table Variables is mapped to SQL Server 2019.
|
|
|
+
|
|
|
+ ```sql
|
|
|
+ USE master;
|
|
|
+ GO
|
|
|
+
|
|
|
+ ALTER DATABASE [tpch10g-btree]
|
|
|
+ SET COMPATIBILITY_LEVEL = 150;
|
|
|
+ GO
|
|
|
+ ```
|
|
|
+
|
|
|
+9. Execute the same command as step 5.
|
|
|
+
|
|
|
+10. Observe the shape of the query execution plan now, that it is a parallel plan, and that a single Hash Joins was chosen given the estimated high number of rows.
|
|
|
+
|
|
|
+11. Click on the **Table Scan** operator in the query execution plan, and hover your mouse over the operator. Observe:
|
|
|
+ - The ***Actual Number of Rows*** is 750000.
|
|
|
+ - The ***Estimated Number of Rows*** is 750000.
|
|
|
+ This indicates the new behavior of TV deferred compilation, with no estimation skew and a better query execution plan, which also executed much faster (~20 seconds).
|
|
|
+
|
|
|
+ 
|
|
|
+
|
|
|
+### Batch Mode on Rowstore
|
|
|
+
|
|
|
+TBA
|