optimize for ad hoc workloads (server configuration option)
Applies to:
SQL Server
Azure SQL Database
Azure SQL Managed Instance
Analytics Platform System (PDW)
The optimize for ad hoc workloads option is used to improve the efficiency of the plan cache for workloads that contain many single use ad hoc batches. When this option is set to 1
, the Database Engine stores a small compiled plan stub in the plan cache when a batch is compiled for the first time, instead of the full compiled plan. This may help to relieve memory pressure by not allowing the plan cache to become filled with compiled plans that aren't reused. However, enabling this option may affect your ability to troubleshoot single-use plans.
The compiled plan stub allows the Database Engine to recognize that this ad hoc batch has been compiled before but has only stored a compiled plan stub, so when this batch is invoked (compiled or executed) again, the Database Engine compiles the batch, removes the compiled plan stub from the plan cache, and adds the full compiled plan to the plan cache.
You can find compiled plan stubs by querying the sys.dm_exec_cached_plans
catalog view and looking for "Compiled Plan" in the cacheobjtype
column. The stub has a unique plan_handle
. The compiled plan stub doesn't have an execution plan associated with it, and querying for the plan handle doesn't return an XML Showplan.
Trace flag 8032 reverts the cache limit parameters to the SQL Server 2005 (9.x) RTM setting, which in general allows caches to be larger. Use this setting when frequently reused cache entries don't fit into the cache and when the optimize for ad hoc workloads option has failed to resolve the problem with plan cache.
Warning
Trace flag 8032 can cause poor performance if large caches make less memory available for other memory consumers, such as the buffer pool.
Remarks
Setting the optimize for ad hoc workloads option to 1
affects only new plans; plans that are already in the plan cache are unaffected.
To affect already cached query plans immediately, the plan cache needs to be cleared using ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE, or SQL Server has to restart.
Recommendations
Avoid having a large number of single-use plans in the plan cache. A common cause of this problem is when the data types of query parameters aren't consistently defined. This particularly applies to the length of strings but can apply to any data type that has a maxlength, a precision, or a scale. For example, if a parameter named @Greeting
is passed as nvarchar(10) on one call and nvarchar(20) on the next call, separate plans are created for each parameter size.
If a query has several parameters and they aren't consistently defined when called, a large number of query plans could exist for each query. Plans could exist for each combination of query parameter data types and lengths that have been used.
If the number of single-use plans take a significant portion of SQL Server Database Engine memory in an OLTP server, and these plans are ad hoc plans, use this server option to decrease memory usage with these objects.
Example
To find the number of single-use cached plans, run the following query:
SELECT objtype, cacheobjtype,
AVG(usecounts) AS Avg_UseCount,
SUM(refcounts) AS AllRefObjects,
SUM(CAST(size_in_bytes AS bigint))/1024/1024 AS SizeInMB
FROM sys.dm_exec_cached_plans
WHERE objtype = 'Adhoc' AND usecounts = 1
GROUP BY objtype, cacheobjtype;
See also
Feedback
Submit and view feedback for