Plan Caching in SQL Server 2008

SQL Server Technical Article

**Writer:**Greg Low, SolidQ Australia

Technical Reviewers From Solid Quality Mentors: Andrew Kelly, Eladio Rincón, Itzik Ben-Gan

Technical Reviewers From Microsoft: Adam Prout, Campbell Fraser, Xin Zhang

Published:  August 2009

Applies to: SQL Server 2008

Summary: This paper explains how SQL Server 2008 allocates memory for plan caching, how query batches are cached and suggests best practices on maximizing reuse of cached plans. It also explains scenarios in which batches are recompiled, and gives best practices for reducing or eliminating unnecessary recompilations and for minimizing plan cache pollution.

Introduction

There are several goals of this white paper. This paper explains how SQL Server 2005 and SQL Server 2008 allocate memory for plan caching, how query batches are cached and suggests best practices on maximizing reuse of cached plans. It also explains scenarios in which batches are recompiled, and gives best practices for reducing or eliminating unnecessary recompilations and for minimizing plan cache pollution. The white paper explains SQL Server's "statement-level recompilation" feature (first introduced in SQL Server 2005) and many tools and utilities that are useful as observation tools in the processes of query compilation, query recompilation, plan caching, and plan reuse.

All material in this white paper applies to both SQL Server 2005 and SQL Server 2008 apart from those areas that are explicitly pointed out as applying to one or the other. This white paper is an update of the white paper “Batch compilation, Recompilation and Plan Caching Issues in SQL Server 2005” by Arun Marathe. For comparisons with SQL Server 2000, readers should refer to that white paper which can be found at https://technet.microsoft.com/en-us/library/cc966425.aspx.

This paper targets these audiences:

  • Users: Persons who use, maintain, and develop applications for SQL Server. Users who are new to SQL Server 2008 and those who are migrating from SQL Server 2005 will find useful information here.
  • Developers: SQL Server developers will find useful background information here.

Recompilations: Definition

Before a query, batch, stored procedure, trigger, prepared statement, or dynamic SQL statement (henceforth, "batch") begins execution on a SQL Server, the batch gets compiled into a plan. The plan is then executed for its effects or to produce results. A batch can contain one or more SELECT, INSERT, UPDATE, DELETE and MERGE statements; and stored procedure calls possibly interleaved by Transact-SQL "glue" or control structures such as SET, IF, WHILE, DECLARE; DDL statements such as CREATE, DROP; and permission-related statements such as GRANT, DENY, and REVOKE. A batch can include definition and use of CLR constructs such as user-defined types, functions, procedures, and aggregates.

Compiled plans are stored into a part of SQL Server's memory called plan cache. Plan cache is searched for possible plan reuse opportunities. If a plan reuse for a batch happens, its compilation costs are avoided. Note that in the SQL Server literature, the word "procedure cache" has been used to describe what is called "plan cache" in this paper. "Plan cache" is more accurate because the plan cache stores query plans of more than just the stored procedures.

In SQL Server parlance, the compilation process mentioned in the previous paragraph is sometimes confusingly referred to as a "recompilation" although the process is simply a "compilation."

Definition of Recompilation: Suppose that a batch has been compiled into a collection of one or more query plans. Before SQL Server begins executing any of the individual query plans, the server checks for validity (correctness) and optimality of that query plan. If one of the checks fails, the statement corresponding to the query plan or the entire batch is compiled again, and a possibly different query plan produced. Such compilations are known as "recompilations." Note in particular that the query plans for the batch need not have been cached. Indeed, some types of batches are never cached, but can still cause recompilations. Take, for example, a batch that contains a literal larger than 8 KB. Suppose that this batch creates a temporary table, and then inserts 20 rows in that table. The insertion of the seventh row will cause a recompilation, but because of the large literal, the batch is not cached.

Most recompilations in SQL Server are performed for good reasons. Some of them are necessary to ensure statement correctness; others are performed to obtain potentially better query execution plans as data in a SQL Server database changes. Sometimes, however, recompilations can slow down batch executions considerably, and then, it becomes necessary to reduce occurrences of recompilations.

Memory Allocated To Plan Caching

Most memory used by SQL Server is allocated to the Buffer Pool, which is used to store data pages. SQL Server steals a proportion of this memory for use in caching query plans. The overall amount of memory available to SQL Server depends upon the amount of memory installed on the server, the architecture of the server, the version and edition of SQL Server and the amount of memory pressure being experienced by SQL Server. This pressure can be internal (SQL Server resources need memory) or external (operating system needs memory). SQL Server is designed to respond to memory pressure when necessary.

Four types of object are stored in the Plan Cache: Object Plans, SQL Plans, Bound Trees and Extended Stored Procedures. SQL Server decides the appropriate allocation of memory to the Plan Cache from the Buffer Pool. The algorithm used for this has been improved in successive service packs since SQL Server 2005 was introduced.

SQL Server Version Cache Pressure Limit

SQL Server 2008 and SQL Server 2005 SP2

75% of visible target memory from 0-4GB + 10% of visible target memory from 4Gb-64GB + 5% of visible target memory > 64GB

SQL Server 2005 RTM and SQL Server 2005 SP1

75% of visible target memory from 0-8GB + 50% of visible target memory from 8Gb-64GB + 25%  of visible target memory > 64GB

SQL Server 2000

SQL Server 2000 4GB upper cap on the plan cache

Table 1: Plan cache memory allocation by SQL Server version

While 32-bit systems may use AWE (Address Window Extensions) memory to extend the available memory beyond the 4G virtual address space limit of the 32-bit architecture, this additional memory can only be used for data pages in the Buffer Pool, not by pages in the Plan Cache. It is not considered visible memory. No such limitation applies to 64-bit systems.

Statement Level Recompilation

Unlike versions of SQL Server prior to SQL Server 2005, during recompiles, SQL Server compiles only the statement that needs to be recompiled, not the entire batch. This "statement-level recompilation" minimizes CPU time and memory during batch recompilations, and obtains fewer compile locks. It avoids the need to break a long stored procedure into multiple short stored procedures just to reduce the recompilation penalty of the long stored procedure.

Plan Caching

Before tackling the issues of recompilations, this paper devotes considerable space to a related and important topic of query plan caching. Plans are cached for possible reuse opportunities. If a query plan is not cached, its reuse opportunity is zero. Such a plan will be compiled every time it is executed, potentially resulting in poor performance. In rare cases, non-caching is a desirable outcome and this paper will point out such cases later on. SQL Server can cache query plans for many types of batches. An enumeration of different types follows. With each type, we describe the necessary conditions for plan reuse. Note that on their own these conditions may not be sufficient to allow for plan reuse.

  • Ad-hoc queries. An ad-hoc query is a batch that contains one or more SELECT, INSERT, UPDATE, DELETE or MERGE statements, does not have parameters and is not pre-prepared. SQL Server requires an exact text match for two ad-hoc queries. The text match is both case- and space-sensitive, even on case-insensitive servers. For example, the following two queries do not share the same query plan. (All Transact-SQL code snippets appearing in this white paper are designed to work with the AdventureWorks2008 sample database, which can be downloaded from Codeplex at http://msftdbprodsamples.codeplex.com/Release/ProjectReleases.aspx?ReleaseId=18407.)
SELECT ProductID
FROM Sales.SalesOrderDetail
GROUP BY ProductID
HAVING AVG(OrderQty) > 5
ORDER BY ProductID;
SELECT productid
FROM Sales.SalesOrderDetail
GROUP BY ProductID
HAVING AVG(OrderQty) > 5
ORDER BY ProductId;
  • Auto-parameterized queries. For certain queries, SQL Server replaces constant literal values with variables, and compiles query plans. This process is called simple parameterization. If a subsequent query differs in only the values of the constants, it will match against the auto-parameterized query. In general, SQL Server auto-parameterizes those queries whose query plans do no depend on particular values of the constant literals. Appendix A contains a list of statement types for which SQL Server does not auto-parameterize.
    As an example of auto-parameterization, the following two queries can reuse a query plan:
SELECT ProductID, SalesOrderID
FROM Sales.SalesOrderDetail
WHERE ProductID > 1000
ORDER BY ProductID;
SELECT ProductID, SalesOrderID
FROM Sales.SalesOrderDetail
WHERE ProductID > 2000
ORDER BY ProductID;
The auto-parameterized form of the above queries is:
SELECT ProductID, SalesOrderID
FROM Sales.SalesOrderDetail
WHERE ProductID > @p1
ORDER BY ProductID;

When values of constant literals appearing in a query can influence a query plan, the query is auto-parameterized. Query plans for such queries are cached, but with constants plugged in, not placeholders such as @p1. SQL Server's "showplan" feature can be used to determine whether a query has been auto-parameterized. For example, the query can be submitted under "set showplan_xml on" mode. If the resulting showplan contains such placeholders as @p1 and @p2, then the query has been auto-parameterized; otherwise not. Showplans in XML format also contain information about values of parameters at both compile-time ('showplan_xml' and 'statistics xml' modes) and execution-time ('statistics xml' mode only): from SQL Server Management Studio, right click on the execution plan, and select “Show Execution Plan XML…” and look for the “ParameterList” tag, where you will see the attributes “ParameterCompiledValue”, and “ParameterRuntimeValue”. In SQL Server 2008, an additional “Parameterized Text” attribute has also been added to the “Statement” node in the returned XML plan.

  • sp_executesql procedure. This is one of the methods that promote query plan reuse. When using sp_executesql, a user or an application explicitly identifies the parameters. For example:
DECLARE @SqlCommand nvarchar(500)
  = N'SELECT p.ProductID, p.Name, p.ProductNumber
      FROM Production.Product AS p
      INNER JOIN Production.ProductDescription AS pd
      ON p.ProductID = pd.ProductDescriptionID
      WHERE p.ProductID = @ProductID';
DECLARE @ParameterDefinition nvarchar(100) = N'@ProductID int';
DECLARE @ProductToLocate int;
SET @ProductToLocate = 4;
EXEC sp_executesql @SqlCommand, @ParameterDefinition,
                   @ProductID = @ProductToLocate;
SET @ProductToLocate = 320;
EXEC sp_executesql @SqlCommand, @ParameterDefinition,
                   @ProductID = @ProductToLocate;

The plan reuse opportunities are predicated on matches of the query-text (the first argument after sp_executesql). The parameter values (4 and 320) are not considered for text matches. Therefore, in the preceding example, plan reuse can happen for the two sp_executesql statements.

  • Prepared queries. This method — which is similar to the sp_executesql method— also promotes query plan reuse. The batch text is sent once at the "prepare" time. SQL Server responds by returning a handle that can be used to invoke the batch at execute time. At execute time, a handle and the parameter values are sent to the server. ODBC and OLE DB expose this functionality via SQLPrepare/SQLExecute and ICommandPrepare. For example, a code snippet using ODBC might look like:
SQLPrepare(hstmt, "SELECT SalesOrderID, SUM(LineTotal) AS SubTotal FROM Sales.SalesOrderDetail sod WHERE SalesOrderID < ? GROUP BY SalesOrderID ORDER BY SalesOrderID", SQL_NTS)
SQLExecute(hstmt)
  • Stored procedures (including triggers). Stored procedures are designed to provide a layer of functional abstraction and to promote plan reuse. The plan reuse is based on the stored procedure or trigger name (even though it is not possible to call a trigger directly). Internally, SQL Server converts the name of the stored procedure to an ID, and subsequent plan reuse happens based on the value of that ID. Plan caching and recompilation behavior of triggers differs slightly from that of stored procedures. We will point out the differences at appropriate places in this document.

    When a stored procedure is compiled for the first time (or in fact any parameterized batch), the values of the parameters supplied with the execution call are used to optimize the statements within that stored procedure. This process is known as "parameter sniffing." If these values are typical, then most calls to that stored procedure will benefit from an efficient query plan. This paper will subsequently discuss techniques that can be used to prevent caching of query plans with atypical stored procedure parameter values.

  • Executing queries via EXEC ( ). SQL Server can cache strings submitted via EXEC for execution. These queries are commonly referred to as "dynamic SQL." For example:

EXEC ( 'SELECT *' + ' FROM Production.Product AS pr
INNER JOIN Production.ProductPhoto AS ph' + '
ON pr.ProductID = ph.ProductPhotoID' +
' WHERE pr.MakeFlag = ' + @mkflag );

Plan reuse is based on the concatenated string that results after replacing variables such as @mkflag in the example above with their actual values when the statement is executed.

Multiple levels of caching

It is important to understand that cache matches at multiple "levels" happen independently of one another. Here is an example. Suppose that Batch 1 (not a stored procedure) contains the following statement (among others):

EXEC dbo.procA;

Batch 2 (also, not a stored procedure) does not text-match with Batch 1, but contains the exact "EXEC dbo.procA;" referring to the same stored procedure. In this case, query plans for Batch 1 and Batch 2 do not match. Nevertheless, whenever "EXEC dbo.procA;" is executed in one of the two batches, a possibility for query plan reuse (and execution context reuse, explained later in this paper) for procA exists if the other batch has executed prior to the current batch, and if the query plan for procA still exists in the plan cache.

Each separate execution of procA gets its own execution context. That execution context is either freshly generated (if all of the existing execution contexts are in use) or reused (if an unused execution context is available). The same type of reuse may happen even if dynamic SQL is executed using EXEC, or if an auto-parameterized statement is executed inside Batch 1 and Batch 2. In short, the following three types of batches start their own "levels" in which cache matches can happen irrespective of whether a cache match happened at any of the containing levels:

  • Stored procedure executions such as "EXEC dbo.stored_proc_name;"
  • Dynamic SQL executions such as "EXEC query_string;"
  • Auto-parameterized queries

Query plans and execution contexts

When a cache-able batch is submitted to SQL Server for execution, it is compiled and a query plan for it is put in the plan cache. Query plans are read-only reentrant structures that are shared by multiple users. There are at most two instances of a query plan at any time in plan cache: one for all of the serial executions and one for all of the parallel executions. The copy for parallel executions is common for all of the degrees of parallelism. (Strictly speaking, if two identical queries posed by the same user using two different sessions with the same session options arrive at a SQL Server simultaneously, two query plans exists while they execute. However, at the end of their executions, plan for only one of them is retained in the plan cache.)

From a query plan, an execution context is derived. Execution contexts hold the values needed for a specific execution of a query plan. Execution contexts are also cached and reused. Each user concurrently executing a batch will have an execution context that holds data (such as parameter values) specific to their execution. Although execution contexts are reused, they are not reentrant (i.e., they are single-threaded). That is, at any point of time, an execution context can be executing only one batch submitted by a session, and while the execution is happening, the context is not given to any other session or user.

The relationships between a query plan and the execution contexts derived from it are shown in the following diagram. There is one query plan, and three execution contexts are derived from it. The execution contexts contain parameter values and user-specific information. The query plan is agnostic to both parameter values and user-specific information.

Figure 1: Query plan and execution context relationship.

A query plan and multiple associated execution contexts can coexist in plan cache. An execution context (without an associated query plan) cannot exist in the plan cache. Whenever a query plan is removed from plan cache, all of the associated execution contexts are also removed along with it. When plan cache is searched for possible plan reuse opportunities, the comparisons are against query plans, not against execution contexts. Once a reusable query plan is found, an available execution context is found (causing execution context reuse) or freshly generated. So query plan reuse does not necessarily imply execution context reuse.

Execution contexts are derived "on the fly" in that before a batch execution begins, a skeleton execution context is generated. As execution proceeds, the necessary execution context pieces are generated and put into the skeleton. This means that two execution contexts need not be identical even after user-specific information and query parameters are deleted from them. Because structures of execution contexts derived from the same query plan can differ from one another, the execution context used for a particular execution has slight impact on performance. Impact of such performance differences diminishes over time as the plan cache gets "hot" and a steady state is reached.

Example: Suppose that a batch B contains an "if" statement. When B begins execution, an execution context for B is generated. Suppose that during this first execution, the "true" branch of the "if" is taken. Further, suppose that B was submitted again by another connection during the first execution. Because the only execution context existing at that moment was in use, a second execution context is generated and given to the second connection. Suppose that the second execution context takes the "false" branch of the "if". After both executions complete, B is submitted by a third connection. Supposing that the third execution of B chooses the "true" branch, the execution will complete slightly faster if SQL Server chose the first execution context of B for that connection rather than the second execution context.

Execution contexts of a batch S can be reused even if the calling sequence of S differs. For example, one calling sequence could be "stored proc 1 --> stored proc 2 --> S", whereas a second calling sequence could be "stored proc 3 --> S". The execution context for the first execution of S can be reused for the second execution of S.

If a batch execution generates an error of severity 11 or higher, the execution context is destroyed. If a batch execution generates a warning (an error with severity 10 or less), the execution context is not destroyed. Thus, even in the absence of memory pressure — which can cause plan cache to shrink— the number of execution contexts (for a given query plan) cached in plan cache can go up and down.

Execution contexts for parallel plans are not cached. A necessary condition for SQL Server to compile a parallel query plan is that the minimum of the number of processors must be more than one after having survived:

  • The processor affinity mask
  • The "max degree of parallelism" server-wide option (possibly set using the "sp_configure" stored procedure)
  • (SQL Server 2008 only) The MAXDOP (Maximum Degree of Parallelism) limits imposed on the resource pool that the query is executing within, by the Resource Governor
  • Any MAXDOP hint on the query

Even if a parallel query plan is compiled (in addition to the serial plan always generated), SQL Server's "Query Execution" component may choose to generate a serial execution context out of it. Any execution contexts derived out of a parallel plan — serial or parallel — are not cached. A parallel query plan, however, is cached.

A change in the SET options for a session can cause SQL Server to need to alter the output from executing a query or to alter the way that a query is processed. The effect of common session-related SET options is discussed later however a number of other SET options deserve special mention at this point.

SET options — most of them showplan-related— can affect compilation, caching, and reuse of query plans and execution contexts in complex ways. The following table summarizes the details.

The table should be read as follows. A batch is submitted to SQL Server under a specific mode specified in the first column. A cached query plan may or may not exist in the plan cache for the submitted batch. Columns 2 and 3 cover the cases when a cached query plan exists; columns 4 and 5 cover the cases when a cached query plan does not exist. Within each category, the cases for query plans and execution contexts are separated. The text explains what happens to a structure (query plan or execution context): whether it is cached, reused, and used.

When a cached query plan exists

When a cached query plan does not exist

Query plan

Execution context

Query plan

Execution context

showplan_text, showplan_all, showplan_xml

Reused (no compilation)

Reused

Cached (compilation)

One execution context is generated, not used, and cached

statistics profile, statistics xml, statistics io, statistics time

Reused (no compilation)

Not reused. A fresh execution context is generated, used, and not cached

Cached (compilation)

One execution context generated, used, and not cached

noexec

Reused (no compilation)

Reused

Cached (compilation)

Execution context is not generated (because of the "noexec" mode).

parseonly (e.g., clicking "parse" in Query Analyzer or Management Studio)

No effect on caching

No effect on caching

No effect on caching

No effect on caching

Table 2: SET options that can affect query compilation and query plan caching.

Costs associated with query plans and execution contexts

With every query plan and execution context, a cost is stored. The cost partially controls how long the plan or context will live in the plan cache. Plans that cost more are more likely to be kept. The cost of an ad-hoc query is zero. Otherwise, the cost of a query plan is a measure of the amount of resources required to produce it. Specifically, the cost is calculated in "number of ticks" with a maximum value of 31, and is composed of three parts:

Cost = I/O cost + context switch cost (a measure of CPU cost) + memory cost

The individual parts of the cost are calculated as follows.

  • Two I/Os cost 1 tick, with a maximum of 19 ticks.
  • Two context switches cost 1 tick, with a maximum of 8 ticks.
  • Sixteen memory pages (128 KB) cost 1 tick, with a maximum of 4 ticks.

The plan cache is distinct from the data cache. In addition, there are other functionality-specific caches. As soon as the size of the plan cache reaches 50% of the buffer pool size, the next plan cache access decrements the ticks of all of the plans by 1 each. Notice that because this decrement is piggybacked on a thread that accesses the plan cache for plan lookup purpose, the decrement can be considered to occur in a lazy fashion. If the sum of the sizes of all of the caches in SQL Server reaches or exceeds 75% of the buffer pool size, a dedicated resource monitor thread gets activated, and it decrements tick counts of all of the objects in all of the caches. A query plan reuse causes the query plan cost to be reset to its initial value. Further detail on how the cache responds to memory pressure is provided in the following article from the SQL Server team blog:

https://blogs.msdn.com/sqlprogrammability/archive/2007/01/16/9-0-memory-pressure-limits.aspx

Roadmap to the rest of the paper

It should be clear to the reader at this point that in order to obtain good SQL Server batch execution performance, the following two things need to happen:

  • Query plans should be reused whenever possible. This avoids unnecessary query compilation costs. Plan reuse also results in better plan cache utilization which, in turn, results in better server performance.
  • Practices that may cause an increase in the number of query recompilations should be avoided. Reducing recompilation counts saves server resources (CPU and memory), and increases the number of batch executions with predictable performance.

The following section describes the details of query plan reuse. When appropriate, best practices that result in better plan reuse are given. In a subsequent section, we describe some common scenarios that may cause an increase in the number of recompilations, and give best practices on their avoidance.

Query Plan Reuse

The plan cache contains query plans and execution contexts. A query plan is conceptually linked to its associated execution contexts. Query plan reuse for a batch S is dependent on S itself (for example, the query text or the stored procedure name), and on some factors external to the batch (for example, the user name that generated S, the application which generated S, the SET options of the connection associated with S, and so on). Some of the external factors are plan-reuse-affecting in that if two identical queries that differ only in one such factor will not be able to use a common plan. Other external factors are not plan-reuse-affecting.

The following list describes the plan-reuse-affecting factors in "typical usage" scenarios. In some cases, entries simply point out when plans are not cached (and hence never reused) no matter what. In general, a query plan can be reused if the server, database, and connection settings of the connection that caused the query plan to be cached are the same as the corresponding settings of the current connection. Second, for reuse it is necessary that the objects that the batch references do not require name resolutions. For example, Sales.SalesOrderDetail does not require name resolution, whereas SalesOrderDetail does because there could be tables named SalesOrderDetail in multiple schemas. In general, two-part object names (that is, schema.object) provide more opportunities for plan reuse.

Factors that affect plan-reuse

Note that if a query plan is not cached, it cannot be reused. Therefore, we explicitly point out only non-cachability; non-reuse is then an implication.

  • For a trigger execution, the number of rows affected by that execution (1 versus n) — as measured by the number of rows in either the inserted or deleted table — is a distinguishing factor in determining a plan cache hit. Note that this behavior is specific to triggers, and does not apply to stored procedures.

    In INSTEAD OF triggers, the "1-plan" is shared by executions that affect both 0 and 1 row, whereas for non-INSTEAD OF ("AFTER") triggers, "1-plan" is only used by executions that affect 1 row and "n-plan" is used by executions that affect both 0 and n rows (n > 1).

  • The execution contexts for bulk insert statements are never cached.

  • A batch that contains any one literal longer than 8 KB is not cached. Therefore, query plans for such batches cannot be reused. (A literal's length is measured after constant folding is applied.)

  • Batches flagged with the "replication flag" (which is associated with a replication user) are not matched with batches without that flag.

  • A batch called from SQL Server common-language runtime (CLR) is not matched with the same batch submitted from outside of CLR. However, two CLR-submitted batches can reuse the same plan. The same observation applies to:

    • CLR triggers and non-CLR triggers
    • Notification queries and non-notification queries
  • SQL Server allows cursor definition on top of a Transact-SQL batch. If the batch is submitted as a separate statement, then it does not reuse (part of the) plan for that cursor.

  • The following SET options are plan-reuse-affecting.

ANSI_NULL_DFLT_OFF

DATEFIRST

ANSI_NULL_DFLT_ON

DATEFORMAT

ANSI_NULLS

FORCEPLAN

ANSI_PADDING

LANGUAGE

ANSI_WARNINGS

NO_BROWSETABLE

ARITHABORT

NUMERIC_ROUNDABORT

CONCAT_NULL_YIELDS_NULL

QUOTED_IDENTIFIER

Table 3: SET options that are plan-reuse-affecting.

Further, ANSI_DEFAULTS is plan-reuse-affecting because it can be used to change the following SET options together (some of which are plan-reuse-affecting): ANSI_NULLS, ANSI_NULL_DFLT_ON, ANSI_PADDING, ANSI_WARNINGS, CURSOR_CLOSE_ON_COMMIT, IMPLICIT_TRANSACTIONS, QUOTED_IDENTIFIER.

The above SET options are plan-reuse-affecting because SQL Server performs "constant folding" (evaluating a constant expression at compile time to enable some optimizations) and because settings of these options affects the results of such expressions.

Settings of some of these SET options are exposed through columns of the sys.syscacheobjects virtual table — for example, "langid" and "dateformat."

Note that values of some of these SET options can be changed using several methods:

  • Using sp_configure stored procedure (for server-wide changes)
  • Using sp_dboption stored procedure (for database-wide changes)
  • Using SET clause of the ALTER DATABASE statement
  • Using the SET statement during a user session

In case of conflicting SET option values, user-level and connection-level SET option values take precedence over database and sever-level SET option values. Further, if a database-level SET option is in effect, then for a batch that references multiple databases (which could potentially have different SET option values), the SET options of the database in whose context the batch is being executed takes precedence over SET options of the rest of the databases.

To avoid SET option-related recompilations, establish SET options at connection time, and ensure that they do not change for the duration of the connection.

  • Batches with unqualified object names may result in non-reuse of query plans. For example, in "SELECT * FROM MyTable;", MyTable may legitimately resolve to HR.MyTable if the user’s default schema is HR but may resolve to Payroll.MyTable if the user’s default schema is Payroll. In such cases, SQL Server does not reuse query plans. If, however, the query "SELECT * FROM dbo.MyTable;" is executed, there is no ambiguity because the object is uniquely identified, and query plan reuse can happen.
  • When a stored procedure is created with "CREATE PROCEDURE WITH RECOMPILE" option, its query plan is not cached whenever that stored procedure is executed. No opportunity of plan reuse exists: every execution of such a procedure causes a fresh compilation. This option can be used to mark stored procedures that are called with widely varying parameters, and for which the best query plans are highly dependent on parameter values supplied during calls.
  • When a stored procedure P is executed using "EXEC … WITH RECOMPILE", P is freshly compiled. Even if a query plan for P preexists in plan cache, and could be reused otherwise, reuse does not happen. The freshly compiled query plan for P is not cached. "EXEC … WITH RECOMPILE" can be used with user-defined functions as well, but only if the EXEC keyword is present. When executing a stored procedure with atypical parameter values, "EXEC  WITH RECOMPILE" can be used to ensure that the fresh query plan does not replace an existing cached plan that was compiled using typical parameter values. Any existing cache entry for the procedure is left unchanged.
  • To avoid multiple query plans for a query that is executed with different parameter values, execute the query using sp_executesql stored procedure. This method is useful if the same query plan is good for all or most of the parameter values.
  • Query plans of temporary stored procedures (both session-scoped and global) are cached, and therefore, can be reused.
  • Plans for queries that create or update statistics (either manually or automatically) are not cached.
  • If a stored procedure refers to a temporary table not created statically in the procedure, the spid (process ID) gets added to the cache key. This means that the plan for the stored procedure would only be reused when executed again by the same session. Temporary tables created statically within the stored procedure do not cause this behavior.

Causes of Recompilations

Recall that recompilation of a batch B occurs when after SQL Server begins executing statements in B, some (or all) of them are compiled again. Reasons for recompilation can be broadly classified into two categories:

  • Plan stability-related reasons. A batch must be recompiled if not doing so would result in incorrect results or actions. Stability-related reasons fall into two sub-categories.
    • Schemas of objects. A batch B may reference many objects (tables, views, indexes, statistics, user-defined functions, and so on), and if schemas of some of the objects have changed since B was last compiled, B needs to be recompiled for statement-correctness reasons.
    • SET options. Some of the SET options affect query results. If the setting of such a plan-reuse-affecting SET option is changed inside of a batch, a recompilation happens.
  • Plan optimality-related reasons. Data in tables that B references may have changed considerably since B was last compiled. In such cases, B may be recompiled for obtaining a potentially faster query execution plan.

The following two sections describe the two categories in detail.

An enumeration of specific actions that cause correctness-related recompilations follows. Because such recompilations must happen, the choice for a user is to not take those actions, or to take them during off-peak hours of SQL Server operation.

  1. Whenever a schema change occurs for any of the objects referenced by a batch, the batch is recompiled. "Schema change" is defined by the following:
    • Adding or dropping columns to a table or view.
    • Adding or dropping constraints, defaults, or rules to/from a table.
    • Adding an index to a table or an indexed view.
    • Dropping an index defined on a table or an indexed view (only if the index is used by the query plan in question).
    • Dropping a statistic (not creating or updating!) defined on a table will cause a correctness-related recompilation of any query plans that use that table. Such recompilations happen the next time the query plan in question begins execution. Updating a statistic (both manual and auto-update) will cause an optimality-related (data related) recompilation of any query plans that uses this statistic.
  2. Running sp_recompile on a stored procedure or a trigger causes them to be recompiled the next time they are executed. When sp_recompile is run on a table or a view, all of the stored procedures that reference that table or view will be recompiled the next time they are run. sp_recompile accomplishes recompilations by incrementing the on-disk schema version of the object in question.
  3. The following operations flush the entire plan cache, and therefore, cause fresh compilations of batches that are submitted the first time afterwards:
    • Detaching a database
    • Upgrading a database to SQL Server 2005
    • Upgrading a database to SQL Server 2008
    • Restoring a database
    • DBCC FREEPROCCACHE command
    • RECONFIGURE command
    • ALTER DATABASE ,,, MODIFY FILEGROUP command
    • Modifying a collation using ALTER DATABASE … COLLATE command

The following operations flush the plan cache entries that refer to a particular database, and cause fresh compilations afterwards.

  • DBCC FLUSHPROCINDB command
  • ALTER DATABASE … MODIFY NAME = command
  • ALTER DATABASE … SET ONLINE command
  • ALTER DATABASE … SET OFFLINE command
  • ALTER DATABASE … SET EMERGENCY command
  • DROP DATABASE command
  • When a database auto-closes
  • When a view is created with CHECK OPTION, the plan cache entries of the database in which the view is created is flushed.
  • When DBCC CHECKDB is run, a replica of the specified database is created. As part of DBCC CHECKDB's execution, some queries against the replica are executed, and their plans cached. At the end of DBCC CHECKDB's execution, the replica is deleted and so are the query plans of the queries posed on the replica.
  • The concept "plan cache entries that refer to a particular database" needs explanation. Database ID is one of the keys of the plan cache. Suppose that you execute the following command sequence.
USE master;
GO
-- A query Q here that references a database called db1
GO
  • Suppose that Q is cached in the plan cache. The database ID associated with Q's plan will be that of the "master," and not that of "db1."
  • When SQL Server's transaction-level snapshot isolation level is on, plan reuse happens as usual. Whenever a statement in a batch under snapshot isolation level refers to an object whose schema has changed since the snapshot isolation mode was turned on, a statement-level recompilation happens if the query plan for that statement was cached and was reused. The freshly compiled query plan is cached, but the statement itself fails (as per that isolation level's semantics). If a query plan was not cached, a compilation happens, the compiled query plan is cached, and the statement itself fails.

4.       The query DBCC FREESYSTEMCACHE() clears a specific cache store.

  • DBCC FREESYSTEMCACHE(‘SQL Plans’) clears the store associated with ad-hoc queries.
  • (SQL Server 2008) DBCC FREESYSTEMCACHE(‘ALL’,’somepool’) clears all cache entries associated with the Resource Governor resource pool named ‘somepool’.

5.       As mentioned earlier, changing one or more of the following SET options after a batch has started execution will cause a recompilation: ANSI_NULL_DFLT_OFF, ANSI_NULL_DFLT_ON, ANSI_NULLS, ANSI_PADDING, ANSI_WARNINGS, ARITHABORT, CONCAT_NULL_YIELDS_NULL, DATEFIRST, DATEFORMAT, FORCEPLAN, LANGUAGE, NO_BROWSETABLE, NUMERIC_ROUNDABORT, QUOTED_IDENTIFIER.

SQL Server is designed to generate optimal query execution plans as data in databases changes. Data changes are tracked using statistics (histograms) in SQL Server's query processor. Therefore, plan optimality-related reasons have close association with the statistics.

Before describing plan optimality-related reasons in detail, we enumerate the conditions under which plan optimality-related recompilations do not happen.

  • When the plan is a "trivial plan." A trivial plan results when the query optimizer determines that given the tables referenced in the query and the indexes existing on them, only one plan is always optimal. Obviously, a recompilation would be futile in such a case. A query that has generated a trivial plan may not always generate a trivial plan, of course. For examples, new indexes might be created on the underlying tables, and so multiple access paths become available to the query optimizer. Additions of such indexes would be detected and a correctness-related recompilation might replace the trivial plan with a non-trivial one.
  • When a query contains the "KEEPFIXED PLAN" hint, its plan is not recompiled for plan optimality-related reasons.
  • When all of the tables referenced in the query plan reside in read-only filegroups or databases, the plan is not recompiled.

High-level overview of query compilation

The following flowchart succinctly describes the batch compilation and recompilation process in SQL Server. The main processing steps are as follows (individual steps will be described in detail later on in this document):

  1. SQL Server begins compiling a query. (As mentioned previously, a batch is the unit of compilation and caching, but individual statements in a batch are compiled one after another.)
  2. All of the "interesting" statistics that may help to generate an optimal query plan are loaded from disk into memory.
  3. If any of the statistics are outdated, they are updated one-at-a-time. The query compilation waits for the updates to finish. Statistics may optionally be updated asynchronously. That is, the query compilation thread is not blocked by statistics updating threads. The compilation thread proceeds with stale statistics.
  4. The query plan is generated. Recompilation thresholds of all of the tables referenced in the query are stored along with the query plan.
  5. At this point, query execution has technically begun. The query plan is now tested for the correctness-related reasons described earlier.
  6. If the plan is not correct for any of the correctness-related reasons, a recompilation is started. Notice that because query execution has technically begun, the compilation just started is a recompilation.
  7. If the plan is "correct," then various recompilation thresholds are compared with either table cardinalities or table modification counters (colmodctr).
  8. If any of the statistics are deemed out-of-date, a recompilation results.
  9. If all of the comparisons succeed, actual query execution begins.

Figure 2: Batch compilation and recompilation process.

Each SELECT, INSERT, UPDATE, DELETE and MERGE statement accesses one or more tables. Table contents change because of such operations as INSERT, UPDATE, DELETE and MERGE. SQL Server's query processor is designed to adapt to such changes by generating potentially different query plans, each optimal at the time it is generated. Table contents are tracked directly using table cardinality, and indirectly using statistics (histograms) on table columns. Each column has a recompilation threshold (RT) associated with it. RT is a function of the number of rows in a table. During query compilation, the query processor loads zero or more statistics defined on tables referenced in a query. These statistics are known as interesting statistics. For every table referenced in a query, the compiled query plan contains:

  • Recompilation threshold
  • A list of all of the statistics loaded during query compilation. For each such statistic, a snapshot value of a counter that counts the number of table modifications is stored. The counter is called colmodctr. A separate colmodctr exists for each table column (except computed non-persisted columns).

The threshold crossing test — which is performed to decide whether to recompile a query plan — is defined by the formula:

| colmodctr(current) – colmodctr(snapshot)) | >= RT

colmodctr(current) refers to the current value of the modification counter, and colmodctr(snapshot) refers to the value of the modification counter when the query plan was last compiled. If threshold crossing succeeds for any of the interesting statistics, the query plan is recompiled. Only the query in question is recompiled.

If a table or an indexed view T has no statistic on it, or none of the existing statistics on T are considered "interesting" during a query compilation, the following threshold-crossing test, based purely on T's cardinality, is still performed.

| card(current) – card(snapshot)) | >= RT

card(current) denotes the number of rows in T at present, and card(snapshot) denotes the row count when the query plan was last compiled.

The following sections describe the important concepts introduced in the "big picture."

Concept of "interesting" statistics

With every query plan P, the optimizer stores the IDs of the statistics that were loaded to generate P. Note that the "loaded" set includes both:

  • Statistics that are used as cardinality estimators of the operators appearing in P
  • Statistics that are used as cardinality estimators in query plans that were considered during query optimization but were discarded in favor of P

In other words, the query optimizer considers all of the loaded statistics as "interesting" for one reason or another.

Recall that statistics can be created or updated either manually or automatically. Statistics updates also happen because of executions of the following commands:

  • CREATE INDEX … WITH DROP EXISTING
  • sp_createstats stored procedure
  • sp_updatestats stored procedure
  • ALTER INDEX REBUILD (but not REORGANIZE)

Recompilation threshold (RT)

The recompilation threshold for a table partly determines the frequency with which queries that refer to the table recompile. RT depends on the table type (permanent versus temporary), and the number of rows in the table (cardinality) when a query plan is compiled. The recompilation thresholds for all of the tables referenced in a batch are stored with the query plans of that batch.

RT is calculated as follows. (n refers to a table's cardinality when a query plan is compiled.)

  • Permanent table
    • If n <= 500, RT = 500.
    • If n > 500, RT = 500 + 0.20 * n.
  • Temporary table
    • If n < 6, RT = 6.
    • If 6 <= n <= 500, RT = 500.
    • If n > 500, RT = 500 + 0.20 * n.
  • Table variable
    • RT does not exist. Therefore, recompilations do not happen because of changes in cardinalities of table variables.

ColModCtr

As mentioned previously, RT is compared against the number of modifications that a column has undergone. The number of modifications that a table has undergone is tracked using a counter (for each column) known as colmodctr. This counter is not transactional. For example, if a transaction starts, inserts 100 rows into a table, and then is rolled back, the changes to colmodctr will not be rolled back. A colmodctr value is stored for each table column (except for computed non-persisted columns). Persisted computed columns have colmodctrs, just like ordinary columns do. Using colmodctr values, changes to a table can be tracked with fine granularity. Colmodctr values are not available to users; they are only available to the query processor.

When a statistic is created or updated (either manually or automatically by the auto-stats feature) on one or more columns of a table or indexed view T, the snapshot value of the colmodctr of the leftmost column is stored in the stats-blob.

Colmodctr(current), mentioned in the "threshold-crossing" test, is the value persisted in SQL Server's metadata when the test is performed during query compilation.

Colmodctr's values are an ever-increasing sequence: colmodctr values are never reset to 0.

Colmodctr values for non-persisted computed columns do not exist. They are derived from the columns that participate in the computation.

Tracking changes to tables and indexed views using colmodctr

Because colmodctr values are used to make recompilation decisions, their values are modified as a table changes. In the following description, we only refer to tables. However, identical observations apply to indexed views. A table can change because of the following statements: INSERT, DELETE, UPDATE, MERGE, bulk insert, and table truncation. The following table defines how colmodctr values are modified. (Note: n is the number of rows).

Statement SQL Server 2008

INSERT

All colmodctr += 1 * n

DELETE

All colmodctr += 1 * n

UPDATE

Typically an update to a row is counted as a modification. However, the execution plan may split updates into deletes and inserts and not collapse them back again. In this case, each modification would count as two modifications.

MERGE

Total of the INSERT, UPDATE and DELETE behavior of the MERGE statement.

Bulk insert

Like n INSERTs. All colmodctr += n. (n is the number of rows bulk inserted.)

Table truncation

Like n DELETEs. All colmodctr += n. (n is the table's cardinality.)

Table 4: SQL Server statements that modify colmodctr values.

Two Special Cases

Plan optimality-related recompilations are handled differently in the following two special cases.

Special case 1: Statistics created on an empty table or indexed view

A user creates an empty table T. She then creates a statistic S on one or more columns of T. Because T is empty, the stats-blob (histogram) is NULL, but the statistic has been created on T. Suppose that S has been found "interesting" during a query compilation. As per the "500 row" rule for recompilation threshold, T would be expected to cause recompilations on SQL Server only after T contains at least 500 rows. Therefore, a user would potentially have suffered from sub-optimal plans until T contains at least 500 rows.

SQL Server detects this special case, and handles it differently. The recompilation threshold for such a table or indexed view is 1. In other words, even the insertion of one row in T can cause a recompilation. When such a recompilation happens, S is updated, and the histogram for S is no longer NULL. After this recompilation, however, the usual rule for recompilation threshold (500 + 0.20 * n) is followed. The recompilation threshold is 1 even when: (1) T has no statistics; or (2) T has no statistics that are considered "interesting" during a query compilation.

Special case 2: Trigger recompilations

All of the plan optimality-related reasons for recompilations are applicable to triggers. In addition, plan optimality-related recompilations for triggers can also happen because of the number of rows in the inserted or deleted tables changing significantly from one trigger execution to the next.

Recall that triggers that affect one row versus multiple rows are cached independently of each other. The numbers of rows in the inserted and deleted tables are stored with the query plan for a trigger. These numbers reflect the row counts for the trigger execution that caused plan caching. If a subsequent trigger execution results in the inserted or deleted table having "sufficiently different" row counts, then the trigger is recompiled (and a fresh query plan with the new row counts is cached).

“Sufficiently different" is defined by:

| log10(n) – log10(m) | > 1         if m > n

| log10(n) – log10(m) | > 2.1      otherwise

where n is the row count of the inserted or deleted table in the cached query plan and m is the row count of the corresponding table for the current trigger execution. If both the "inserted" and "deleted" tables have rows, the above-mentioned test is separately performed for both of them. As an example of the calculation, a row count change from 10 to 100 does not cause a recompilation, whereas a change from 10 to 101 does.

Statistics-related recompilations can be identified by the "EventSubClass" column of the profiler trace (to be described later in this paper) containing the string "Statistics changed".

Query Optimizer Decisions

An issue not directly related to the topic of this document is: given multiple statistics on the same set of columns in the same order, how does the query optimizer decide which ones to load during query optimization? The answer is not simple, but the query optimizer uses such guidelines as: Give preference to recent statistics over older statistics; Give preference to statistics computed using FULLSCAN option to those computed using sampling; and so on.

There is a potential of confusion regarding the "cause and effect" relationship between plan optimality-related compilations, recompilations, and statistics creation/updates. Recall that statistics can be created or updated manually or automatically. Only compilations and recompilations cause automatic creation or updates of statistics. On the other hand, when a statistic is created or updated (manually or automatically), there is an increased chance of recompilation of a query plan which might find that statistic "interesting."

Best Practices

Four best practices for reducing plan optimality-related batch recompilations are given next:

Best practice: Because a change in cardinality of a table variable does not cause recompilations, consider using a table variable instead of a temporary table when faced with a problem of excessive recompilations. However, the use of table variables can lead to poorer query plans. Distribution statistics are not stored for table variable and cardinality is only available during recompiles, not during initial compilation. One has to experiment whether this is the case, and make an appropriate trade-off.

Best practice: The KEEP PLAN query hint changes the recompilation thresholds for temporary tables, and makes them identical to those for permanent tables. Therefore, if changes to temporary tables are causing many recompilations, this query hint can be used. The hint can be specified using the following syntax:

SELECT b.col4, SUM(a.col1)
FROM dbo.PermTable AS a
INNER JOIN #TempTable AS b
ON a.col1 = b.col2
WHERE b.col3 < 100
GROUP BY b.col4
OPTION (KEEP PLAN);

Best practice: To avoid recompilations due to plan optimality-related (statistic update-related) reasons totally, the KEEPFIXED PLAN query hint can be specified using the syntax:

SELECT c.TerritoryID, COUNT(*) AS Number, c.SalesPersonID
FROM Sales.Store AS s
INNER JOIN Sales.Customer AS c
ON s.CustomerID = c.CustomerID
WHERE s.Name LIKE '%Bike%'
AND c.SalesPersonID > 285
GROUP BY c.TerritoryID, c.SalesPersonID
ORDER BY Number DESC
OPTION (KEEPFIXED PLAN);

With this option in effect, recompilations can only happen because of correctness-related reasons — for example, the schema of a table referenced by a statement changes, or a table is marked with sp_recompile procedure.

Suppose that a query with OPTION(KEEPFIXED PLAN) hint is being compiled for the first time, and compilation causes auto-creation of a statistic. If SQL Server can get a special "stats lock," a recompilation happens and the statistic is auto-created. If the "stats lock" cannot be obtained, there is no recompilation, and the query is compiled without that statistic.

Best practice: Do not turn off automatic updates of statistics for indexes and statistics defined on a table or indexed view. While doing so will ensure that plan optimality-related recompilations caused by those objects will stop, the query optimizer will no longer be sensitive to data changes in those objects and sub-optimal query plans might result. Turn off automatic update of statistics only as a last resort after exhausting all of the other alternatives.

Compilations, Recompilations, and Concurrency

Suppose that a stored procedure is submitted for execution using "EXEC dbo.SP1;" and further suppose that while SQL Server is compiling SP1, another request "EXEC dbo.SP1;" referring to the same stored procedure is received. Compilations are serialized, but recompilations are not serialized. If it is a plan-optimality-related recompile, one thread will recompile it and the other threads utilizing the procedure will continue using the old plan until the compilation is finished. However, if it is a plan-stability-related recompile, all threads will recompile concurrently and the last one completed is the one that is cached.

Compilations, Recompilations, and Parameter Sniffing

"Parameter sniffing" refers to a process whereby SQL Server's execution environment "sniffs" the current parameter values during compilation or recompilation, and passes it along to the query optimizer so that they can be used to generate potentially faster query execution plans. The word "current" refers to the parameter values present in the statement call that caused a compilation or a recompilation. Parameter values are sniffed during compilation or recompilation for the following types of batches:

  • Stored procedures
  • Queries submitted via sp_executesql
  • Prepared queries
  • OPTION(RECOMPILE) query hint.

For such a query (could be SELECT, INSERT, UPDATE, DELETE or MERGE), both the parameter values and the current values of local variables are sniffed. (Without OPTION(RECOMPILE), only parameter values are sniffed). The values sniffed (of parameters and local variables) are those that exist at the place in the batch just before the statement with the OPTION(RECOMPILE) hint. In particular, for parameters, the values that came along with the batch invocation call are not sniffed.

OPTIMIZE FOR Query Hint

The OPTIMIZE FOR query hint can assist in avoiding parameter sniffing problems caused by the first execution of a procedure where atypical parameter values are passed. For example, consider the query plans for the following two queries:

USE AdventureWorks2008;
GO
SELECT soh.SalesOrderID,soh.DueDate,
       sod.OrderQty,sod.ProductID
FROM Sales.SalesOrderHeader AS soh
INNER JOIN Sales.SalesOrderDetail AS sod
ON soh.SalesOrderID = soh.SalesOrderID
WHERE soh.CustomerID > 30117;
SELECT soh.SalesOrderID,soh.DueDate,
       sod.OrderQty,sod.ProductID
FROM Sales.SalesOrderHeader AS soh
INNER JOIN Sales.SalesOrderDetail AS sod
ON soh.SalesOrderID = soh.SalesOrderID
WHERE soh.CustomerID > 10000;

In these queries, the plan produced is highly dependent on the value of the CustomerID. Only one SalesOrderHeader row matches the predicate soh.CustomerID > 30117 but a large number of rows match the predicate soh.CustomerID > 10000. If this SELECT statement was included in a stored procedure, the effectiveness of the query plan produced would be significantly influenced by the value passed to the query on its first execution. If a particular value is known to be typical, SQL Server can be instructed to optimize for that value via a query hint as shown in the following procedure definition:

CREATE PROCEDURE dbo.ProductOrderDetails
@CustomerID int
AS
SELECT soh.SalesOrderID,soh.DueDate,
       sod.OrderQty,sod.ProductID
FROM Sales.SalesOrderHeader AS soh
INNER JOIN Sales.SalesOrderDetail AS sod
ON soh.SalesOrderID = soh.SalesOrderID
WHERE soh.CustomerID > @CustomerID
OPTION (OPTIMIZE FOR (@CustomerID = 30117));
GO

Now, compare the query plans from the following two executions:

EXEC dbo.ProductOrderDetails 30117;
EXEC dbo.ProductOrderDetails 10000;

You will see that the query plans are now identical. It is important to note however that this hint should only ever be used to supply typical parameter values. In the case above, we have optimized the plan for a CustomerID of 30117 but created a poor plan for a CustomerID of 10000.

For values that vary widely, SQL Server 2008 offers an additional option. OPTIMIZE FOR UNKNOWN requests SQL Server to use statistical distributions to determine the plan rather than the supplied value. For example, we will modify our previous procedure via the following code:

ALTER PROCEDURE dbo.ProductOrderDetails
@CustomerID int
AS
SELECT soh.SalesOrderID,soh.DueDate,
       sod.OrderQty,sod.ProductID
FROM Sales.SalesOrderHeader AS soh
INNER JOIN Sales.SalesOrderDetail AS sod
ON soh.SalesOrderID = soh.SalesOrderID
WHERE soh.CustomerID > @CustomerID
OPTION (OPTIMIZE FOR UNKNOWN);
GO
Now, again compare the query plans from the following two executions:
EXEC dbo.ProductOrderDetails 30117;
EXEC dbo.ProductOrderDetails 10000;

Further details on this query hint are provided at https://msdn.microsoft.com/en-us/library/ms181714.aspx.

Identifying Recompilations

SQL Server's Profiler makes it easy to identify batches that cause recompilations. Start a new profiler trace and select the following events under Stored Procedures event class. (To reduce the amount of data generated, it is recommended that you de-select any other events.)

  • SP:Starting
  • SP:StmtStarting
  • SP:Recompile
  • SP:Completed

In addition, to detect statistics-update-related recompilations, select the "Auto Stats" event under "Objects" class.

Now start SQL Server Management Studio, and execute the following Transact-SQL code:

USE AdventureWorks2008;
GO
DROP PROCEDURE DemoProc1;
GO
CREATE PROCEDURE DemoProc1
AS
CREATE TABLE #t1 (a int, b int);
SELECT * FROM #t1;
GO
EXEC DemoProc1;
GO
EXEC DemoProc1;
GO

Pause the profiler trace, and you will see the following sequence of events.

EventClass TextData EventSubClass

SP:Starting

EXEC DemoProc1

SP:StmtStarting

-- DemoProc1 CREATE TABLE #t1 (a int, b int)

SP:StmtStarting

-- DemoProc1 SELECT * FROM #t1

SP:Recompile

Deferred compile

SP:StmtStarting

-- DemoProc1 SELECT * FROM #t1

SP:Completed

EXEC DemoProc1

SP:Starting

EXEC DemoProc1

SP:StmtStarting

-- DemoProc1 CREATE TABLE #t1 (a int, b int)

SP:StmtStarting

-- DemoProc1 SELECT * FROM #t1

SP:Completed

EXEC DemoProc1

Table 5: Events generated from executing the Transact-SQL code example.

The event sequence indicates that "SELECT * FROM #t1" was the statement that caused the recompilation. The EventSubClass column indicates the reason for the recompilation. In this case, when DemoProc1 was compiled before it began execution, the "CREATE TABLE" statement could be compiled. The subsequent "SELECT" statement could not be compiled because it referred to a temporary table #t1 that did not exist at the time of the initial compilation. The compiled plan for DemoProc1 was thus incomplete. When DemoProc1 started executing, #t1 got created and then the "SELECT" statement could be compiled. Because DemoProc1 was already executing, this compilation counts as a recompilation as per our definition of recompilation. The reason for this recompilation is correctly given as "deferred compile."

It is interesting to note that when DemoProc1 is executed again, the query plan is no longer incomplete. The recompilation has inserted a complete query plan for DemoProc1 into the plan cache. Therefore, no recompilations happen for the second execution.

The statements causing recompilations can also be identified by selecting the following set of trace events.

  • SP:Starting
  • SP:StmtCompleted
  • SP:Recompile
  • SP:Completed

If the above example is run after selecting this new set of trace events, the trace output looks like the following.

EventClass TextData EventSubClass

SP:Starting

EXEC DemoProc1

SP:StmtCompleted

-- DemoProc1 CREATE TABLE #t1 (a int, b int)

SP:Recompile

Deferred compile

SP:StmtCompleted

-- DemoProc1 SELECT * FROM #t1

SP:Completed

EXEC DemoProc1

SP:Starting

EXEC DemoProc1

SP:StmtCompleted

-- DemoProc1 CREATE TABLE #t1 (a int, b int)

SP:StmtCompleted

-- DemoProc1 SELECT * FROM #t1

SP:Completed

EXEC DemoProc1

Table 6: Events generated from executing the Transact-SQL code example.

Notice that in this case, the statement causing the recompilation is printed after the SP:Recompile event. This method is somewhat less obvious than the first one. Therefore, we shall trace the first set of profiler trace events henceforth.

To see all of the possible recompilation reasons reported for the SP:Recompile event, issue the following query:

SELECT tsv.subclass_name, tsv.subclass_value
FROM sys.trace_events AS te
INNER JOIN sys.trace_subclass_values AS tsv
ON te.trace_event_id = tsv.trace_event_id
WHERE te.name = 'SP:Recompile'
AND tsv.subclass_value  < 1000
ORDER BY tsv.subclass_value;

The output of the above query is as follows.

SubclassName SubclassValue Detailed reason for recompilation

Schema changed

1

Schema, bindings, or permissions changed between compile and execute.

Statistics changed

2

Statistics changed.

Deferred compile

3

Recompile because of DNR (Deferred Name Resolution). Object not found at compile time, deferred check to run time.

Set option change

4

Set option changed in batch.

Temp table changed

5

Temp table schema, binding, or permission changed.

Remote rowset changed

6

Remote rowset schema, binding, or permission changed.

For browse permissions changed

7

Permissions changed in FOR BROWSE (deprecated DBLIB option)

Query notification environment changed

8

Query notification environment changed

Partition view changed

9

SQL Server sometimes adds data-dependent implied predicates to WHERE clauses of queries in some indexed views. If the underlying data changes, such implied predicates become invalid, and the associated cached query plan needs recompilation.

Cursor options changed

10

Change in cursor options

Option (Recompile) requested

11

Recompile was requested

Parameterized plan flushed

12

Parameterized plan was flushed from cache (SQL Server 2008)

Test plan linearization

13

(SQL Server 2008) For internal test only

Plan affecting database version changed

14

(SQL Server 2008)

Table 7: Recompilation reasons reported for the SP:Recompile event.

Recompilations due to mixing DDL and DML

Mixing Data Definition Language (DDL) and Data Manipulation Language (DML) statements within a batch or stored procedure is a poor design practice because it can cause unnecessary recompilations. The following example illustrates this using a stored procedure. (The same phenomenon happens for a batch also. Because SQL Server Profiler does not provide the necessary tracing events, we cannot observe it in action.) Clean up the previous example (or prepare for a rerun) by executing the following:

DBCC FREEPROCCACHE;
DROP PROCEDURE MixDDLDML;
DROP TABLE tab1;
DROP TABLE tab2;
GO
Next, create the following stored procedure.:
CREATE PROCEDURE MixDDLDML
AS
CREATE TABLE tab1 (a int);            -- DDL
SELECT * FROM tab1;                   -- DML
CREATE INDEX nc_tab1idx1 ON tab1(a);  -- DDL
SELECT * FROM tab1;                   -- DML
CREATE TABLE tab2 (a int);            -- DDL
SELECT * FROM tab2;                   -- DML
GO
EXEC MixDDLDML;
GO

In the profiler trace output, the following sequence of events can be observed.

EventClass TextData EventSubClass

SP:Starting

EXEC MixDDLDML

SP:StmtStarting

-- MixDDLDML CREATE TABLE tab1 (a int)       --DDL

SP:StmtStarting

-- MixDDLDML SELECT * FROM tab1   -- DML

SP:Recompile

Deferred compile

SP:StmtStarting

-- MixDDLDML SELECT * FROM tab1   -- DML

SP:StmtStarting

-- MixDDLDML CREATE INDEX nc_tab1idx1 ON tab1(a)    -- DDL

SP:StmtStarting

-- MixDDLDML SELECT * FROM tab1   -- DML

SP:Recompile

Deferred compile

SP:StmtStarting

-- MixDDLDML SELECT * FROM tab1   -- DML

SP:StmtStarting

-- MixDDLDML CREATE TABLE tab2 (a int)       --DDL

SP:StmtStarting

-- MixDDLDML SELECT * FROM tab2   -- DML

SP:Recompile

Deferred compile

SP:StmtStarting

-- MixDDLDML SELECT * FROM tab2   -- DML

SP:Completed

EXEC MixDDLDML

Table 8: Events generated from executing the Transact-SQL code example.

Here is how the MixDDLDML procedure is compiled.

  1. During the first compilation (not recompilation) of MixDDLDML, a skeleton plan for it is generated. Because tables tab1 and tab2 do not exist, plans for the three "SELECT" statements cannot be produced. The skeleton contains plans for the two "CREATE TABLE" statements and the one "CREATE INDEX" statement.
  2. When the procedure begins execution, table tab1 is created. Because there is no plan for the first "SELECT * FROM tab1", a statement-level recompilation happens.
  3. The second "SELECT * FROM tab1" causes a recompilation because a plan for that query does not yet exist.
  4. Next, "tab2" gets created. "SELECT * FROM tab2" causes a recompilation because a plan for that query did not exist.

In conclusion, three recompilations happen for this example however they are statement-level rather than stored procedure-level.

If the stored procedure is written as follows, an interesting phenomenon is observed.

CREATE PROCEDURE DDLBeforeDML
AS
CREATE TABLE tab1 (a int);            -- DDL
CREATE INDEX nc_tab1idx1 ON tab1(a);  -- DDL
CREATE TABLE tab2 (a int);            -- DDL
SELECT * FROM tab1;                   -- DML
SELECT * FROM tab1;                   -- DML
SELECT * FROM tab2;                   -- DML
GO
EXEC DDLBeforeDML;
GO

In the profiler trace output, the following sequence of events can be observed.

EventClass TextData EventSubClass

SP:Starting

EXEC DDLBeforeDML

SP:StmtStarting

-- DDLBeforeDML CREATE TABLE tab1 (a int)       -- DDL

SP:StmtStarting

-- DDLBeforeDML CREATE INDEX nc_tab1idx1 ON tab1(a)    -- DDL

SP:StmtStarting

-- DDLBeforeDML CREATE TABLE tab2 (a int)       -- DDL

SP:StmtStarting

-- DDLBeforeDML SELECT * FROM tab1   --DML

SP:Recompile

Deferred compile

SP:StmtStarting

-- DDLBeforeDML SELECT * FROM tab1    --DML

SP:StmtStarting

-- DDLBeforeDML   SELECT * FROM tab1    --DML

SP:Recompile

Deferred compile

SP:StmtStarting

-- DDLBeforeDML SELECT * FROM tab1    --DML

SP:StmtStarting

-- DDLBeforeDML SELECT * FROM tab2           -- DML

SP:Recompile

Deferred compile

SP:StmtStarting

-- DDLBeforeDML SELECT * FROM tab2           -- DML

SP:Completed

EXEC DDLBeforeDML

Table 9: Events generated from executing the Transact-SQL code example.

Because of statement-level recompilations, three recompilations still happen. When compared with the MixDDLDML stored procedure, the number of recompilations has not reduced. It is important to consider not only the number of recompilations but the cost of them. Statement level recompilations are much lower in cost than batch level recompilations.

Recompilations due to number of column modifications

Consider the following stored procedure and its execution.

USE tempdb;
GO
CREATE PROCEDURE RowCountDemo
AS
BEGIN
    CREATE TABLE #t1 (a int, b int);
    DECLARE @i int = 0;
    WHILE (@i < 20)
    BEGIN
       INSERT INTO #t1 (a,b) VALUES (@i, 2*@i - 50);
       SELECT a
       FROM #t1
       WHERE a < 10 OR ((b > 20 OR a >=100) AND (a < 10000))
       GROUP BY a;
       SET @i = @i + 1;
    END;
END;
GO
EXEC RowCountDemo;
GO

Recall that the recompilation threshold for a temporary table is 6 when the table is empty when the threshold is calculated. When RowCountDemo is executed, a "statistics changed"-related recompilation can be observed after #t1 contains exactly 6 rows. By changing the upper bound of the "while" loop, more recompilations can be observed.

Recompilations due to SET option changes

Consider the following stored procedure.

USE AdventureWorks2008;
GO
CREATE PROCEDURE SetOptionsDemo
AS
BEGIN
    SET ANSI_NULLS OFF;
    SELECT p.Size AS ProductSize,
           SUM(p.ListPrice) AS TotalPrice
    FROM Production.Product AS p
    INNER JOIN Production.ProductCategory AS pc
    ON p.ProductSubcategoryID = pc.ProductCategoryID
    WHERE p.Color = 'Black'
    GROUP BY p.Size
    ORDER BY ProductSize, TotalPrice;
END;
GO
SET ANSI_NULLS ON;
EXEC SetOptionsDemo;     -- causes a recompilation
GO
EXEC SetOptionsDemo;     -- does not cause a recompilation
GO

When SetOptionsDemo is executed, the "SELECT" query is compiled with "ANSI_NULLS" ON. When SetOptionsDemo begins execution, the value of that SET option changes because of "SET ANSI_NULLS OFF", and therefore the compiled query plan is no longer "valid." It is therefore recompiled with "ANSI_NULLS " OFF. The second execution does not cause a recompilation because the cached plan is compiled with "ANSI_NULLS" OFF.

Tools and Commands

This section contains descriptions of various tools and commands that exist in observing and debugging recompilation-related scenarios.

Dynamic Management Objects

A number of dynamic management views and functions are useful when exploring plan reuse. In particular, the following objects are most helpful:

sys.dm_exec_cached_plans

sys.dm_exec_query_plan

sys.dm_exec_plan_attributes

sys.dm_exec_sql_text

sys.dm_exec_cached_plan_dependent_object

As an example, the following query is useful in exploring the current plan cache contents:

SELECT cp.objtype AS PlanType,
       OBJECT_NAME(st.objectid,st.dbid) AS ObjectName,
       cp.refcounts AS ReferenceCounts,
       cp.usecounts AS UseCounts,
       st.text AS SQLBatch,
       qp.query_plan AS QueryPlan
FROM sys.dm_exec_cached_plans AS cp
CROSS APPLY sys.dm_exec_query_plan(cp.plan_handle) AS qp
CROSS APPLY sys.dm_exec_sql_text(cp.plan_handle) AS st;

sys.syscacheobjects  virtual table

This virtual table conceptually exists only in the master database, although it can be queried from any database. The cacheobjtype column of this virtual table is particularly interesting. When cacheobjtype = "Compiled Plan", the row refers to a query plan. When cacheobjtype = "Executable Plan", the row refers to an execution context. As we have explained, each execution context must have its associated query plan, but not vice versa. One other column of interest is the objtype column: it indicates the type of object whose plan is cached (for example, "Adhoc", "Prepared", and "Proc"). The setopts column encodes a bitmap indicating the SET options that were in effect when the plan was compiled. Sometimes, multiple copies of the same compiled plan (that differ in only setopts column) are cached in a plan cache. This indicates that different connections are using different sets of SET options, a situation that is often undesirable. The usecounts column stores the number of times a cached objects has been reused since the time the object was cached.

This virtual table is maintained for backwards compatibility with SQL Server 2000. Dynamic Management Objects should now be used in preference. The virtual table is documented here: https://msdn.microsoft.com/en-us/library/ms187815.aspx.

DBCC FREEPROCCACHE

This command removes all of the cached query plans and execution contexts from the plan cache. It is not advisable to run this command on a production server because it can adversely affect performance of running applications. This command is useful to control plan cache's contents when troubleshooting a recompilation issue.

DBCC FLUSHPROCINDB( db_id )

This command removes all of the cached plans from the plan cache for a particular database. It is not advisable to run this command on a production server because it can adversely affect performance of running applications.

DBCC FREESYSTEMCACHE(cache[,resource pool])

This command removes all the plans in a particular cache. The value ‘ALL’ can also be provided for the cache. Optionally in SQL Server 2008, the effect of this command can be limited by a Resource Governor resource pool name. This latter option could be useful for cleaning up ad-hoc query plans associated with a specific resource pool, when the ‘Sys Plans’ cache option is also provided. It is not advisable to run this command on a production server unless its effect is fully understood as it can adversely affect performance of running applications.

Extended Events (SQL Server 2008)

SQL Server 2008 introduced a new eventing system known as Extended Events. It allows tracing of events as they occur and details of events as they are fired to be written to a variety of synchronous and asynchronous targets. A number of these events are related to plan caching. You can see the full list of available events by executing the following command:

SELECT dxp.[name] AS Package,
       dxo.[name] AS EventName,
       dxo.capabilities_desc AS Capabilities,
       dxo.[description] AS Description
FROM sys.dm_xe_packages AS dxp
INNER JOIN sys.dm_xe_objects AS dxo
ON dxp.[guid] = dxo.package_guid
WHERE dxo.object_type = 'event'
ORDER BY Package,EventName;

You can find details on the Extended Events system at https://msdn.microsoft.com/en-us/library/bb630354.aspx.

Profiler Trace Events

The following profiler trace events are relevant for observing and debugging plan caching, compilation, and recompilation behaviors.

  • 'Cursors: CursorRecompile' for observing recompilations caused by cursor-related batches.
  • 'Objects: Auto Stats' for observing the statistics updates caused by SQL Server's "auto-stats" feature.
  • 'Performance: Show Plan All For Query Compile' is useful for tracing batch compilations. It does not distinguish between a compilation and a recompilation. It produces showplan data in textual format (similar to the one produced using "set showplan_all on" option).
  • 'Performance: Show Plan XML For Query Compile' is useful for tracing batch compilations. It does not distinguish between a compilation and a recompilation. It produces showplan data in XML format (similar to the one produced using "set showplan_xml on" option).
  • 'Stored Procedures: SP: Recompile' fires when a recompilation happens. Other events in the "Stored Procedures" category are also useful — for example, SP:CacheInsert, SP:StmtStarting, SP:CacheHit, SP:Starting, and so on.

PerfMon Counters

Values of the following perfmon counters are relevant when debugging performance problems that may be caused by excessive compilations and recompilations.

Performance object Counters

SQLServer: Buffer Manager

Lazy writes/sec, Total pages

SQLServer: Cache Manager

Cache Hit Ratio, Cache Object Counts, Cache Pages, Cache Use Counts/sec

SQLServer: Memory Manager

SQL Cache Memory (KB)

SQLServer:SQL Statistics

Auto-Param Attempts/sec, Batch Requests/sec, Failed Auto-Params/sec, Safe Auto-Params/sec, SQL Compilations/sec, SQL Re-Compilations/sec, Unsafe Auto-Params/sec

Table 10: Perfmon counters used for debugging query performance problems.

Plan Cache Pollution Issues

While the plan cache generally is self-maintaining, poor application coding practices can cause the plan cache to become polluted with a large number of query plans that are unlikely to be reused.

As an example, while it is convenient to use the AddParameterWithValue(parametername, parametervalue) method of the SqlCommand object in .NET coding, doing so does not specify the data type of the parameter. For string parameters, this can be particularly troubling. If the parameter value is initially “hello”, a query plan with an nvarchar parameter length of 5 will be cached after the command is executed. When the query is re-executed with a parameter value of “trouble”, the command will appear to be different as it has an nvarchar parameter with a length of 7. The more the command is executed, the more the plan cache will become full of plans for different length string parameters. This is particularly troubling for commands with multiple string parameters as plans will end up being stored for all combinations of all lengths of all the parameters.

To work around such a problem, the application could use a method to add the parameter that allows specifying the data type precisely. As an example, nvarchar(100) might be used as the data type for each execution in the above example, if we know that all possible parameter lengths are less than 100. Ad-hoc queries generated by end-user query tools can also cause a similar problem where many combinations of similar queries can end up becoming cached.

In SQL Server 2008, there are three options that can help in dealing with plan cache pollution issues.

  • FORCED PARAMETERIZATION can be set at the database level. This makes SQL Server become much more aggressive in deciding which queries to auto-parameterize. The down-side of this option is that it could potentially introduce parameter-sensitivity problems. (This option was also available in SQL Server 2005).
  • OPTIMIZE FOR ADHOC WORKLOADS is a new sp_configure server level option. When set, SQL Server only caches a plan stub on the first execution of an ad-hoc query. The next time the same query is executed, the full plan is stored. Plan stubs are much smaller than query plans and this option ensures that the plan cache is not filled by query plans that have never been reused.
  • DBCC FREESYSTEMCACHE can be used to clear the cache of plans associated with a particular Resource Governor resource pool. This could be useful when executed periodically if ad-hoc queries are able to be isolated into identifiable resource pools. (This command was also available in SQL Server 2005 but the option to clear a specific resource pool was added in SQL Server 2008).

Conclusion

SQL Server caches query plans for a variety of statement types submitted to it for execution. Query plan caching allows for query plan reuse, avoids compilation penalty, and utilizes plan cache better. Some coding practices hinder query plan caching and reuse, and therefore, should be avoided. SQL Server detects opportunities for query plan reuse. In particular, query plans can be non-reusable for two reasons: (a) Schema of an object appearing in a query plan can change thereby making the plan invalid; and (b) Data in tables referred to by a query plan can change enough to make a plan sub-optimal. SQL Server detects these two classes of conditions at query execution time, and recompiles a batch or pieces of it as necessary. Poor Transact-SQL coding practices both at server and at application data access layer can increase recompilation frequency or plan cache pollution and adversely affect SQL Server's performance. Such situations can be debugged and corrected in many cases.

Appendix A: When Does SQL Server Not Auto-Parameterize Queries?

Auto-parameterization is a process whereby SQL Server replaces literal constants appearing in a SQL statement with such parameters as @p1 and @p2. The SQL statement's compiled plan is then cached in plan cache in parameterized form so that a subsequent statement that differs only in the values of the literal constants can reuse the cached plan. As mentioned in Section 4, only those SQL statements for which parameter values do not affect query plan selection are auto-parameterized.

SQL Server's LPE (Language Processing and Execution) component auto-parameterizes SQL statements. When QP (query processor) component realizes that values of literal constants does not affect query plan choice, it declares LPE's attempt of auto-parameterization "safe" and auto-parameterization proceeds; otherwise, auto-parameterization is declared "unsafe" and is aborted. Values of some of the perfmon counters mentioned in Section 11.5 ('SQLServer: SQL Statistics' category) report statistical information on auto-parameterization.

The following list enumerates the statement types for which SQL Server does not auto-parameterize.

Queries with IN clauses are not auto-parameterized. For example:

  • WHERE ProductID IN (707, 799, 905)
  • BULK INSERT statement.
  • UPDATE statement with a SET clause that contains variables. For example:
UPDATE Sales.Customer
SET CustomerType = N'S'
WHERE CustomerType = @a;
  • A SELECT statement with UNION.
  • A SELECT statement with INTO clause.
  • A SELECT or UPDATE statement with FOR BROWSE clause.
  • A statement with query hints specified using the OPTION clause.
  • A SELECT statement whose SELECT list contains a DISTINCT.
  • A statement with the TOP clause.
  • A WAITFOR statement.
  • A DELETE or UPDATE with FROM clause.
  • When FROM clause has one of the following:
    • More than one table
    • TABLESAMPLE clause
    • Table-valued function or table-valued variable
    • Full-text table
    • OPENROWSET
    • XMLUNNEST
    • OPENXML
    • OPENQUERY
    • IROWSET
    • OPENDATASOURCE
    • Table hints or index hints
  • When a SELECT query contains a sub-query
  • When a SELECT statement has GROUP BY, HAVING, or COMPUTE BY
  • Expressions joined by OR in a WHERE clause.
  • Comparison predicates of the form expr <> non-null-constant.
  • Full-text predicates.
  • When the target table in an INSERT, UPDATE, or DELETE is a table-valued function.
  • Statements submitted via EXEC string.
  • Statements submitted via sp_executesql, sp_prepare, and sp_prepexec without parameters are auto-parameterized under TF 447.
  • When query notification is requested.
  • When a query contains a common table expression list.
  • When a query contains FOR UPDATE clause.
  • When an UPDATE contains an ORDER BY clause.
  • When a query contains the GROUPING clause.
  • INSERT statement of the form: INSERT INTO T DEFAULT VALUES.
  • INSERT … EXEC statement.
  • When a query contains comparison between two constants. For example, WHERE 20 > 5
  • If by doing auto-parameterization, more than 1000 parameters can be created.

For more information:

https://www.microsoft.com/sqlserver/: SQL Server Web site

https://technet.microsoft.com/en-us/sqlserver/: SQL Server TechCenter

https://msdn.microsoft.com/en-us/sqlserver/: SQL Server DevCenter 

Did this paper help you? Please give us your feedback. Tell us on a scale of 1 (poor) to 5 (excellent), how would you rate this paper and why have you given it this rating? For example:

  • Are you rating it high due to having good examples, excellent screen shots, clear writing, or another reason?
  • Are you rating it low due to poor examples, fuzzy screen shots, or unclear writing?

This feedback will help us improve the quality of white papers we release.

Send feedback.