DBCC FREEPROCCACHE (Transact-SQL)
Removes all elements from the plan cache, removes a specific plan from the plan cache by specifying a plan handle or SQL handle, or removes all cache entries associated with a specified resource pool.
Syntax
DBCC FREEPROCCACHE [ ( { plan_handle | sql_handle | pool_name } ) ] [ WITH NO_INFOMSGS ]
Arguments
( { plan_handle | sql_handle | pool_name } )
plan_handle uniquely identifies a query plan for a batch that has executed and whose plan resides in the plan cache. plan_handle is varbinary(64) and can be obtained from the following dynamic management objects:sql_handle is the SQL handle of the batch to be cleared. sql_handle is varbinary(64) and can be obtained from the following dynamic management objects:
pool_name is the name of a Resource Governor resource pool. pool_name is sysname and can be obtained by querying the sys.dm_resource_governor_resource_pools dynamic management view.
To associate a Resource Governor workload group with a resource pool, query the sys.dm_resource_governor_workload_groups dynamic management view. For information about the workload group for a session, query the sys.dm_exec_sessions dynamic management view.
WITH NO_INFOMSGS
Suppresses all informational messages.
Remarks
Use DBCC FREEPROCCACHE to clear the plan cache carefully. Freeing the plan cache causes, for example, a stored procedure to be recompiled instead of reused from the cache. This can cause a sudden, temporary decrease in query performance. For each cleared cachestore in the plan cache, the SQL Server error log will contain the following informational message: "SQL Server has encountered %d occurrence(s) of cachestore flush for the '%s' cachestore (part of plan cache) due to 'DBCC FREEPROCCACHE' or 'DBCC FREESYSTEMCACHE' operations." This message is logged every five minutes as long as the cache is flushed within that time interval.
Result Sets
When the WITH NO_INFOMSGS clause is not specified, DBCC FREEPROCCACHE returns:
"DBCC execution completed. If DBCC printed error messages, contact your system administrator."
Permissions
Requires ALTER SERVER STATE permission on the server.
Examples
A. Clearing a query plan from the plan cache
The following example clears a query plan from the plan cache by specifying the query plan handle. To ensure the example query is in the plan cache, the query is first executed. The sys.dm_exec_cached_plans and sys.dm_exec_sql_text dynamic management views are queried to return the plan handle for the query. The plan handle value from the result set is then inserted into the DBCC FREEPROCACHE statement to remove only that plan from the plan cache.
USE AdventureWorks;
GO
SELECT * FROM Person.Address;
GO
SELECT plan_handle, st.text
FROM sys.dm_exec_cached_plans
CROSS APPLY sys.dm_exec_sql_text(plan_handle) AS st
WHERE text LIKE N'SELECT * FROM Person.Address%';
GO
Here is the result set.
plan_handle text
-------------------------------------------------- -----------------------------
0x060006001ECA270EC0215D05000000000000000000000000 SELECT * FROM Person.Address;
(1 row(s) affected)
-- Remove the specific plan from the cache.
DBCC FREEPROCCACHE (0x060006001ECA270EC0215D05000000000000000000000000);
GO
B. Clearing all plans from the plan cache
The following example clears all elements from the plan cache. The WITH NO_INFOMSGS clause is specified to prevent the information message from being displayed.
DBCC FREEPROCCACHE WITH NO_INFOMSGS;
C. Clearing all cache entries associated with a resource pool
The following example clears all cache entries associated with a specified resource pool. The sys.dm_resource_governor_resource_pools view is first queried to obtain the value for pool_name.
SELECT * FROM sys.dm_resource_governor_resource_pools;
GO
DBCC FREEPROCCACHE (default);
GO
See Also
Reference
Concepts
Change History
Updated content |
---|
Corrected the resource pool information in the introduction and added information in the Arguments section about ways to obtain Resource Governor pool name information. |
Added example C. |