Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
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 option might 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 might affect your ability to troubleshoot single-use plans.
The compiled plan stub allows the Database Engine to recognize that this ad hoc batch was compiled previously, and only stores a compiled plan stub. 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 a graphical or 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 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.
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.
Avoid having a large number of single-use plans in the plan cache. Common causes include:
Data types of query parameters that 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.
Queries that aren't parameterized. If a query has one or more parameters for which hard-coded values get submitted to the Database Engine, 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 were 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.
If the optimize for ad hoc workloads option is enabled, you can't view execution plans for single-use queries, because only the plan stub is cached. Depending on your environment and workload, you might benefit from the following two features:
The Query Store feature, introduced in SQL Server 2016 (13.x), helps you quickly find performance differences caused by query plan changes. Query Store is enabled by default on new databases in SQL Server 2022 (16.x) and later versions.
Forced parameterization can improve the performance of certain databases by reducing the frequency of query compilations and recompilations. Databases that benefit from forced parameterization generally experience high volumes of concurrent queries from sources such as point-of-sale applications.
Forced parameterization can cause performance issues due to parameter sensitivity. For more information, see Investigate and resolve parameter-sensitive issues. For SQL Server 2022 (16.x) and later versions, you can also enable Parameter Sensitive Plan optimization.
To find the number of single-use cached plans, run the following query:
SELECT objtype,
cacheobjtype,
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;
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining
Learning path
Optimize query performance in Azure SQL - Training
Optimize query performance in Azure SQL
Documentation
Server configuration: max degree of parallelism - SQL Server
Learn about the max degree of parallelism (MAXDOP) option. See how to use it to limit the number of processors that SQL Server uses in parallel plan execution.
Server configuration: cost threshold for parallelism - SQL Server
Learn about the cost threshold for parallelism option. See how its value affects whether SQL Server runs parallel plans for queries, and find out how to set it.
sys.dm_os_wait_stats (Transact-SQL) - SQL Server
Returns information about all the waits encountered by threads that executed.