SQL Server 2016 Upgrade Testing with the New Cardinality Estimator: Context Matters

This week I’ve been working with SQL Server 2016 and it’s been a lot of fun – this is truly a great release from the SQL Server team.  Yesterday I was working on some upgrade testing with regard to the new Cardinality Estimator (CE), introduced in SQL Server 2104 and well explained in this whitepaper written by my friend Joe Sack.  If you are upgrading to SQL Server 2014 or 2016, you should test not just your upgrade process, but also the performance of your queries with the new CE.  In some cases we have seen good/great improvements in query performance with the new CE, but in other cases we have seen significant regressions which dramatically affect overall system performance.

There are a variety of things to look for when testing beyond just query duration and resource use – you should also be looking at estimates and plan shape, which means capturing the execution plan.  I was doing just that yesterday, and in my testing I was changing the compatibility mode for the user database and running my queries with the different CEs.  I was then confirming the CE version used for the query by looking at the plan and checking the CardinalityEstimationModelVersion attribute.  Remember that CE version is tied to the compatibility mode, and the CE that will be used is tied to the current database context.  So if you’re running cross database or distributed queries, this is something to which you need to pay attention.

Consider this scenario…

I have a new installation of SQL Server 2016, and I restore my user database to the instance.  By default the compatibility is not changed unless the database you’re restoring has a compatibility level of 90 (remember you can upgrade from SQL Server 2005+ to any other version).  In that case, it will automatically be bumped up to 100 for both SQL Server 2014 and SQL Server 2016.  For more details on supported compatibility levels for versions and the differences between the levels, see ALTER Database Compatibility Level.

Because this is a new installation of SQL Server 2016, the system databases have compatibility level of 130.  I restore two user databases to my instance (previously running on SQL Server 2012), call them AdventureWorks and WideWorldImporters.  I leave the compatibility level for AdventureWorks at 110, and set it to 130 for WideWorldImporters.  I then start running queries, some of which are specific to a database, others which query both databases.

In the case where I’m in the context of AdventureWorks, the old CE version used – even when I query the WideWorldImporters database.  And if I’m in the WideWorldImporters database, querying across to AdventureWorks, the new CE is used.  Here’s setup code:

/*
	Restore the databases
	(change locations as appropriate)
*/
USE [master];
GO

RESTORE DATABASE [WideWorldImporters]
	FROM  DISK = N'C:\Backups\WideWorldImporters-Full.bak'
	WITH  FILE = 1,
	MOVE N'WWI_Primary' TO N'C:\Databases\WideWorldImporters\WideWorldImporters.mdf',
	MOVE N'WWI_UserData' TO N'C:\Databases\WideWorldImporters\WideWorldImporters_UserData.ndf',
	MOVE N'WWI_Log' TO N'C:\Databases\WideWorldImporters\WideWorldImporters.ldf',
	MOVE N'WWI_InMemory_Data_1' TO N'C:\Databases\WideWorldImporters\WideWorldImporters_InMemory_Data_1',
	NOUNLOAD,
	REPLACE,
	STATS = 5;
GO

RESTORE DATABASE [AdventureWorks2016]
	FROM  DISK = N'C:\Backups\AW2014_Base.bak'
	WITH  FILE = 1,
	MOVE N'AdventureWorks2014_Data' TO N'C:\Databases\AdventureWorks2016\AdventureWorks2016_Data.mdf',
	MOVE N'AdventureWorks2014_Log' TO N'C:\Databases\AdventureWorks2016\AdventureWorks2016_Log.ldf',
	NOUNLOAD,
	REPLACE,
	STATS = 5;
GO

/*
	Set the compatibility levels
*/
USE [master];
GO
ALTER DATABASE [WideWorldImporters] SET COMPATIBILITY_LEVEL = 130;
GO
ALTER DATABASE [AdventureWorks2016] SET COMPATIBILITY_LEVEL = 110;
GO

First, run the query in the context of WideWorldImporters, with the execution plan displayed:

USE [WideWorldImporters];
GO

SET STATISTICS XML ON;
GO

SELECT
	[o].[CustomerID],
	[c].[StoreID],
	[o].[OrderDate],
	[ol].[StockItemID],
	[ol].[Quantity],
	[ol].[UnitPrice]
FROM [WideWorldImporters].[Sales].[Orders] [o]
JOIN [WideWorldImporters].[Sales].[OrderLines] [ol] on [o].[OrderID] = [ol].[OrderID]
JOIN [AdventureWorks2016].[Sales].[Customer] [c] ON [c].[CustomerID] = [o].[CustomerID]
WHERE [o].[OrderDate] BETWEEN '2016-05-01' AND '2016-05-31'
ORDER BY [o].[OrderDate] DESC;
GO

SET STATISTICS XML OFF;
GO

If you open up the graphical plan, and display the Properties window (F4) and then click on the SELECT operator in the plan, I can see that the CardinalityEstimationModelVersion is 130 (you can also view the XML and do a search to find it there):

Execution plan using the new CE
Execution plan using the new CE

Now run the query in the context of AdventureWorks, again with the execution plan displayed:

USE [AdventureWorks2016];
GO

SET STATISTICS XML ON;
GO

SELECT
	[o].[CustomerID],
	[c].[StoreID],
	[o].[OrderDate],
	[ol].[StockItemID],
	[ol].[Quantity],
	[ol].[UnitPrice]
FROM [WideWorldImporters].[Sales].[Orders] [o]
JOIN [WideWorldImporters].[Sales].[OrderLines] [ol] on [o].[OrderID] = [ol].[OrderID]
JOIN [AdventureWorks2016].[Sales].[Customer] [c] ON [c].[CustomerID] = [o].[CustomerID]
WHERE [o].[OrderDate] BETWEEN '2016-05-01' AND '2016-05-31'
ORDER BY [o].[OrderDate] DESC;
GO

SET STATISTICS XML OFF;
GO

This time when you look at the graphical plan, the CardinalityEstimationModelVersion is 70, indicating it’s using the old CE:

Execution plan using the old CE
Execution plan using the old CE

In this example, I have users connecting to both databases, and they can be querying one database or both.  Note that if you happen to keep users in the context of one database (e.g. a user database that has no data in it, but you use as a “gateway” to other database), then the compatibility level for that database will determine what CE the queries use.  The exception to all this, of course, is the CE-related traceflags.  You can override the compatibility level and force the optimizer to use a specific CE by using one of two trace flags:

  • Use Trace Flag 9481 to revert to the legacy CE behavior from the context of a database with a compatibility level of 120 or higher
  • Use Trace Flag 2312 to enable to the new CE from the context of a database with a compatibility level below 120

Therefore, when you’re testing your upgrade to SQL Server 2014 or 2016, take the time to look beyond the basics.  Upgrading is not just about making sure nothing breaks, it’s also about making sure that performance doesn’t degrade, even if you don’t change hardware (especially if you don’t change hardware!).  We don’t typically expect that upgrading to a newer software version would negatively affect performance, but because the change the SQL Server’s Cardinality Estimator is significant, this is one you definitely want to test.

 

Leave a Reply

Your email address will not be published. Required fields are marked *

Other articles

A Fond Farewell

If you haven’t guessed from the title, I’m writing this post because I am leaving SQLskills. This Friday, January 14th, is my last day, and

Explore

Imagine feeling confident enough to handle whatever your database throws at you.

With training and consulting from SQLskills, you’ll be able to solve big problems, elevate your team’s capacity, and take control of your data career.