SQL Server Plan Cache Limits

Last week on SQLPerformance.com I blogged about ad hoc workloads and how they impact performance, noting plan cache bloat, and I had a comment asking about SQL Server plan cache limits.  Kimberly mentions them in her classic post Plan cache and optimizing for adhoc workloads, but I thought I’d put the information into a blog post because I always have trouble finding the original references: Plan Caching in SQL Server 2008 (which is still accurate for SQL Server 2019, as far as I know) and Plan Cache Internals.

There are two limitations related to the plan cache:

  • Number of entries
  • Total size in MB (based on server memory)

By default, the plan cache is limited to 160,036 total entries (40,009 entries per bucket), and size based on max server memory (for SQL Server 2008+ and SQL Server 2005 SP2):

75% of visible target memory from 0 to 4GB                                                                                                             + 10% of visible target memory from 4GB to 64GB                                                                                                   + 25% of visible target memory > 64GB

Here’s the math:

 

SQL Server default plan cache size limits

SQL Server default plan cache size limits

 

If you have an ad hoc workload, you’ll often hit the max number of entries before you hit the space limit, particularly if you have the optimize for ad hoc workloads server option enabled, which stores the plan stub for an ad hoc query on initial execution, rather than the entire plan (the plan stub consumes less space, so this is an attempt to reduce bloat).

For pure ad hoc workloads, if you’re seeing SOS_CACHESTORE spinlock contention, you can use trace flag 174 to increase the number of entries to 160,001 per bucket (640,004 total), which is applicable for:

  • SQL Server 2012 SP1 CU14+
  • SQL Server 2012 SP2 CU5+
  • SQL Server 2014 CU2+
  • SQL Server 2014 SP1 CU1+
  • SQL Server 2016+

Very rarely, I have seen instances where customers have used trace flag 8032 to increase the total size of the plan cache.  This trace flag uses the plan cache limits for SQL Server 2005 RTM:

75% of visible target memory from 0 to 4GB                                                                                                             + 50% of visible target memory from 4GB to 64GB                                                                                                   + 25% of visible target memory > 64GB

The math is below, but note that this can significantly affect the memory available for the buffer pool and this is something I don’t typically recommend…use with caution.

SQL Server plan cache limits with TF 8032

SQL Server plan cache limits with TF 8032

Summary

If you’re seeing plan cache bloat due to an ad hoc workload, take note of the space consumed by your plan cache and consider enabling the optimize for ad hoc setting, and possibly enabling TF 174.  Both of those are short term fixes – ideally you look to parameterize stable queries that are executed most frequently to reduce the number of entries in the plan cache.

Query Store in SQL Server 2019 (CTP 3.0)

Friends, CTP 3.0 dropped today, and it includes some changes for Query Store in SQL Server 2019!  I am so excited!!  I’ve downloaded it and have WideWorldImporters installed and have a lot of testing planned, but if you’re impatient, guess what?  The documentation is already updated!  If you check out the ALTER DATABASE SET page you will see that Query Store now has a new option for QUERY_CAPTURE_MODE: CUSTOM.  For those of you with ad hoc workloads, this will help.

Remember that with QUERY_CAPTURE_MODE, the default for SQL Server 2016 and SQL Server 2017 is ALL, and for Azure SQL Database it is AUTO.  I previously recommended that everyone use AUTO, as this means you do not capture queries that are insignificant (thresholds determined by Microsoft and not publicly documented, but it’s at least 3 executions and some amount of of CPU).

The CUSTOM option allows you determine what queries are captured based on:

  • EXECUTION_COUNT
  • TOTAL_COMPILE_CPU_TIME_MS
  • TOTAL_EXECUTION_CPU_TIME_MS

These three options operate in an OR manner.  For example, if I set the values as follows:

  • EXECUTION_COUNT = 100
  • TOTAL_COMPILE_CPU_TIME_MS = 60000
  • TOTAL_EXECUTION_CPU_TIME_MS = 60000

A query would only be captured in Query Store if it executed at least 100 times, if the total compile time for the query was at least 60 seconds, or if the total execution time (for all executions) was at least 60 seconds.

You also control the interval across which those options are tracked via the STALE_CAPTURE_POLICY_THRESHOLD setting.  This can be as low as 1 hour and as high as 7 days.  If I set it to 1 hour, then if the query did not exceed any of the thresholds within the 1 hour time frame, it wouldn’t be captured.  Ultimately, you can control what Query Store captures based on executions, compile time, or duration, which will help keep the size of the Query Store data much more manageable.

In addition to these new options, the default values for two settings changed in SQL Server 2019.  Specifically:

  • MAX_STORAGE_SIZE_MB increased from 100MB to 1000MB
  • QUERY_STORE_CAPTURE_MODE changed from ALL to AUTO

I have a fair bit of testing I want to do to see these settings in action, but I wanted to give you all a heads up if you’re looking to upgrade to 2019 when it’s released, or if you have had a less-than-positive experience with Query Store and wonder if it’s something you’ll ever be able to use.  The answer is yes, and this is a step in the direction to make it happen.  More to come!

Queries with OPTION (RECOMPILE) and Query Store

 

Last week in our IEPTO2 class I was asked about queries with OPTION (RECOMPILE) and Query Store. Specifically: Do queries that have the OPTION (RECOMPILE) hint go into Query Store, AND do queries in a stored procedure created with the RECOMPILE option go into Query Store? I knew the answer to the first question, and was pretty sure I know the answer to the second one, but I wanted to test to verify. Let’s take a look.

TL;DR In case you’re too busy to keep reading, the answer is yes to both.

Setup

We are using the WideWorldImporters database, which you can download from Github.  I’m running the latest CU for SQL Server 2017, but this is applicable for any version of Query Store (SQL Server 2016 and higher) and Azure SQL Database.  The code below will enable Query Store, set QUERY_CAPTURE_MODE to ALL (to understand the different various and what’s recommended for production, check out my Query Store Settings post), and then clear out anything that’s in Query Store.  I don’t typically recommend that you clear out Query Store, but we’re restoring a demo database, and this is a demo, so I want to make sure we start fresh.  Lastly, we’ll create a stored procedure to use for testing that is created with RECOMPILE and then completely free procedure cache.  Note that adding the RECOMPILE option to a stored procedure is not something I recommend – it means that the entire stored procedure will recompile every time it is executed.  I also don’t recommend freeing procedure cache in production – this is just for demo purposes.


USE [master];
GO
ALTER DATABASE [WideWorldImporters] SET QUERY_STORE = ON;
GO
ALTER DATABASE [WideWorldImporters] SET QUERY_STORE (OPERATION_MODE = READ_WRITE, QUERY_CAPTURE_MODE = ALL);
GO
ALTER DATABASE [WideWorldImporters] SET QUERY_STORE CLEAR;
GO

DROP PROCEDURE IF EXISTS Sales.usp_GetOrderInfo 
GO

CREATE PROCEDURE Sales.usp_GetOrderInfo
(@OrderID INT)
WITH RECOMPILE
AS
BEGIN
SELECT 
o.OrderID,
o.CustomerID,
o.OrderDate,
ol.Quantity,
ol.UnitPrice
FROM Sales.Orders o
JOIN Sales.OrderLines ol
ON o.OrderID = ol.OrderID
WHERE o.OrderID = @OrderID;
END
GO

DBCC FREEPROCCACHE;
GO

Testing

First, execute an ad hoc query, one that is not part of a stored procedure, that has the OPTION (RECOMIPLE) hint:


SELECT
i.InvoiceID,
i.CustomerID,
i.InvoiceDate,
il.Quantity,
il.UnitPrice
FROM Sales.Invoices i
JOIN Sales.InvoiceLines il
ON i.InvoiceID = il.InvoiceID
WHERE i.InvoiceID = 54983
OPTION (RECOMPILE);
GO 10

If we check the plan cache, you’ll notice that there is no evidence that this query has executed:


SELECT 
qs.execution_count,
st.text, 
qs.creation_time
FROM sys.dm_exec_query_stats AS [qs] 
CROSS APPLY sys.dm_exec_sql_text ([sql_handle]) [st]
CROSS APPLY sys.dm_exec_query_plan ([plan_handle]) [p]
WHERE [st]. LIKE '%Sales.Invoices%';
GO

Plan cache after ad hoc query with OPTION (RECOMPILE)

 

But if we look in Query Store we do see the query:


SELECT
[qsq].[query_id], 
[qsp].[plan_id],
[qsq].[object_id],
[rs].[count_executions],
[rs].[last_execution_time],
[rs].[avg_duration],
[rs].[avg_logical_io_reads],
[qst].[query_sql_text],
TRY_CONVERT(XML, [qsp].[query_plan]) AS [QueryPlan_XML],
[qsp].[query_plan] 
FROM [sys].[query_store_query] [qsq] 
JOIN [sys].[query_store_query_text] [qst]
ON [qsq].[query_text_id] = [qst].[query_text_id]
JOIN [sys].[query_store_plan] [qsp] 
ON [qsq].[query_id] = [qsp].[query_id]
JOIN [sys].[query_store_runtime_stats] [rs] 
ON [qsp].[plan_id] = [rs].[plan_id]
WHERE [qst].[query_sql_text] LIKE '%Sales.Invoices%';
GO

Query Store capturing ad hoc query with OPTION (RECOMPILE)

 

If we expand the query_sql_text column (middle text removed for space reasons) you can see that the text includes OPTION (RECOMPILE).  This is pretty cool.

Query with OPTION (RECOMIPLE) stored in Query Store

 

Now let’s execute the stored procedure we created with RECOMPILE and then check the plan cache:


EXEC Sales.usp_GetOrderInfo 57302;
GO 10

SELECT 
qs.execution_count,
st.text, 
qs.creation_time
FROM sys.dm_exec_query_stats AS [qs] 
CROSS APPLY sys.dm_exec_sql_text ([sql_handle]) [st]
CROSS APPLY sys.dm_exec_query_plan ([plan_handle]) [p]
WHERE [st]. LIKE '%Sales.Orders%';
GO

Plan cache after stored procedure created with OPTION (RECOMPILE)

 

And when we check Query Store we do see the query:


SELECT
[qsq].[query_id], 
[qsp].[plan_id],
[qsq].[object_id],
OBJECT_NAME([qsq].[object_id]) AS ObjectName,
[rs].[count_executions],
[rs].[last_execution_time],
[rs].[avg_duration],
[rs].[avg_logical_io_reads],
[qst].[query_sql_text],
TRY_CONVERT(XML, [qsp].[query_plan]) AS [QueryPlan_XML],
[qsp].[query_plan] /* nvarchar(max) */
FROM [sys].[query_store_query] [qsq] 
JOIN [sys].[query_store_query_text] [qst]
ON [qsq].[query_text_id] = [qst].[query_text_id]
JOIN [sys].[query_store_plan] [qsp] 
ON [qsq].[query_id] = [qsp].[query_id]
JOIN [sys].[query_store_runtime_stats] [rs] 
ON [qsp].[plan_id] = [rs].[plan_id]
WHERE OBJECT_NAME([qsq].[object_id]) = 'usp_GetOrderInfo';
GO

Query from stored procedure created with OPTION (RECOMIPLE) stored in Query Store

 

Summary

Regardless of where OPTION (RECOMPILE) is used – at the statement level for an ad hoc query or a statement within a stored procedure – and when the RECOMPILE option is used at the procedure level during creation or execution – the query text, the plan, and the execution statistics still get captured within Query Store.