Tag Archive: Plan Cache


Clearing the Plan Cache

While at SQL Saturday #63 in Dallas, I got some questions about clearing the plan cache.  This evolved into an email discussion; which resulted in me writing up some example scripts.  Since I received some good feedback, I thought this would be a good opportunity to turn them into a blog post.

Warning: These scripts should almost never be run on a production system.  These are meant for debugging and testing on DEV.  If you do run these on PROD, be sure to understand the consequences.

I could see running these on PROD in a few limited cases.  For example, if you have a query that is stuck with a bad plan in cache, you can use these scripts to remove that individual plan.  Another possibility would be to clear out the adhoc plans, perhaps just after you have enabled the optimize for adhoc workloads setting.

Examining the Plan Cache

The Plan Cache is where SQL Server stores the Execution Plans for any queries or stored procedures it has run.  The purpose of this is to enable SQL Server to reuse Execution Plans for each subsequent run of the query or stored procedure.  This allows SQL Server to scale up as more requests begin to pile on.

To examine the Plan Cache you can start by querying the sys.dm_exec_cached_plans DMV.


-- look at the plan cache, list all plans
select * from sys.dm_exec_cached_plans;
go

This is not very useful by itself.  In order to make this query a bit more useful, we can link in either the Query Text or the Query Plan by using two other DMVs: sys.dm_exec_sql_text and sys.dm_exec_query_plan respectively.


-- link in the sql text
select decp.*, dest.text
from sys.dm_exec_cached_plans decp
cross apply sys.dm_exec_sql_text(decp.plan_handle) dest;
go

-- link in the query plan
select decp.*, deqp.query_plan
from sys.dm_exec_cached_plans decp
cross apply sys.dm_exec_query_plan(decp.plan_handle) deqp;
go

And if you wish to see both the Query Text and the Query Plan together, you can link multiple DMVs in the same query.


-- link in both
select decp.*, dest.text, deqp.query_plan
from sys.dm_exec_cached_plans decp
cross apply sys.dm_exec_sql_text(decp.plan_handle) dest
cross apply sys.dm_exec_query_plan(decp.plan_handle) deqp;
go

Clearing the Plan Cache

As I work through clearing the Plan Cache, I’m going to start with the broadest example, and then get more granular as we go along.  If you need to clear the entire Plan Cache, you can do so with a DBCC FREEPROCCACHE command.

I feel the need to issue another warning here, and reiterate that this is almost always a bad idea on a production system.


-- clears everything in the plan cache
dbcc freeproccache;
go

Clearing by Database

If clearing the entire Plan Cache seems a bit excessive, as well it should, then you can get a wee bit more focused by only clearing the plans for a particular database.  This can be achieved by using the DBCC FLUSHPROCINDB command.  This is an undocumented command in SQL 2008, however, you can read about it under the SQL 2005 documentation.

As with clearing the entire cache, this is probably not something you want to do with a production system unless you have a good reason.  You may have one database that is a special case, which needs to be tamed.


-- clear the plan cache for a particular database
declare @v_DBID tinyint;

select @v_DBID = dbid from sys.sysdatabases where name = 'AdventureWorks2008R2';

dbcc flushprocindb (@v_DBID);
go

Clearing by Object Type

Next, let’s look at clearing the Plan Cache for a particular type of object.  By using DBCC FREESYSTEMCACHE we can choose to clear out the Adhoc Plans, Stored Procedure Plans, Views, or Extended Stored Procedures.

Most likely, the ones you will be interested in are Adhoc Plans and Stored Procedures.


-- clear plans for a particular type of object

-- clear sql plans: adhoc sql, prepared statements
dbcc freesystemcache('SQL Plans');
go

-- clear object plans: stored procedures, functions, triggers
dbcc freesystemcache('Object Plans');
go

-- clear bound trees: views, constraints, defaults
dbcc freesystemcache('Bound Trees');
go

-- clear extended stored procedures
dbcc freesystemcache('Extended Stored Procedures');
go

Like a broken record, I gotta remind you that it is a bad idea to do this on a production system.

Optimize for Adhoc Workloads

The primary reason you may wish to clear out the Adhoc Plans from your cache, is if you have just enabled the SQL Server setting ‘optimize for adhoc workloads‘.  This setting tells SQL Server not to cache the Execution Plans for Adhoc queries until they have been run more than once.  This helps keep Plan Cache Bloat under control.

You can enable this setting by using sp_configure.


-- show advanced options - enable all options to be seen / set
use [master]
go
exec sp_configure 'show advanced options', 1
go
reconfigure
go
reconfigure with override
go

-- optimize for ad hoc workloads
sp_configure 'optimize for ad hoc workloads', 1
go
reconfigure
go
reconfigure with override
go

-- verify change
sp_configure 'optimize for ad hoc workloads'
go

Once you have enabled this setting, the Single-Use Adhoc Plans will remain in cache until either the SQL Service has been restarted, or you have explicitly cleared the Plan Cache of Adhoc Plans by using the code example above.

Resource Governor

If you are using Resource Governor, then you have the option of clearing the Plan Cache for a particular Resource Pool.  Resource Governor allows you to create various Resource Pools and then designate a certain percentage of CPU or Memory to that pool.

In order to get a list of the Resource Pools that are defined on your system, you can query the sys.dm_resource_governor_resource_pools DMV.


-- list the resource governor pools
select distinct name as 'Resource Governor Pools'
from sys.dm_resource_governor_resource_pools;
go

Once you have identified the Resource Pool that needs to have its associated Cached Plans cleared, you can clear the plans by using the DBCC FREEPROCCACHE command.


-- clear the default resource governor pool
dbcc freeproccache ('default');
go

-- clear the internal resource governor pool
dbcc freeproccache ('internal');
go

-- clear the default resource governor pool
dbcc freeproccache ('YOURRESOURCEGOVERNORPOOL');
go

Again, please do not do this on a production system unless you are certain this is what you need.

Clearing a Single Plan

If you have a particular query which is causing you problems, for example, it got compiled with a bad plan, then, one option is to remove the offending plan from the cache, which will cause a recompile.  There is no guarantee, however, that the new plan will be any better than the old plan.

You may wish to capture the existing plan so that you can compare it with the new plan.  This way you can explore what the differences are, and focus your tuning efforts there.

To find the query plan for a particular query we will need a search string; the SQL from your query.  We will place your query inside of mine, so we can search the Plan Cache for it.  It is not necessary to use the entire text of the query, that would be a bit cumbersome. All we need is enough to make it unique, or unique enough that we can find it in the results.


-- or it may be even better to search by the sql text
-- so that you only see the ones that interest you
-- also link in the query plan so that you can analyze it
select decp.usecounts, decp.size_in_bytes, dest.text, decp.plan_handle, deqp.query_plan
from sys.dm_exec_cached_plans decp
cross apply sys.dm_exec_sql_text(decp.plan_handle) dest
cross apply sys.dm_exec_query_plan(decp.plan_handle) deqp
where dest.text like '%PLACE YOUR SQL CODE SNIPPET HERE%';
go

Once you have identified the offending plan, it is a simple matter to remove it from the cache.  Use the plan_handle with the DBCC FREEPROCCACHE command to clear it from the Plan Cache.


-- once you find the plan you wish to prune
-- place the plan_handle in the following statement
dbcc freeproccache (0x0600010010450926B8E00C07000000000000000000000000);
go

So this is the only one of the options where I can see a valid case for doing it on Production.  All the same, be careful and understand what you are doing.  It is important to clear only the Query Plan that is needed, and no more.

Conclusion

It is important to keep tabs on what is going on in your Plan Cache.  Being able to clear out all or part of your Plan Cache can be a powerful debugging technique.  Please bear in mind that this is not something that should be done on a Production server without careful consideration of the side effects.

However, playing with this in DEV can help you understand more of what is happening under the covers of SQL Server.

My original plan was to publish this article on April 18th in celebration of Tax Filing Day.  However, life has a way of happening, so I filed IRSQL Form 1433 and applied for an extension.

Say Brother, can you spare me some Cache?

Have you used up all of your Plan Cache?  Would you like a refund?  Are ad-hoc queries bloating your Plan Cache?  How can you tell?  What are ad-hoc queries?  What’s a Plan Cache?

Ad-hoc Queries

Ad-hoc queries are TSQL queries that are issued directly against the database.  Typically, the query text is created directly in the application, then sent directly to the database for the data.  This is very common in web-based applications such as ASP or PHP.  However, you also see this with traditional, desktop application written in C/C++ or Java.

Contrast this with Stored Procedures.  Similar to procedures in other programming languages, Stored Procedures can be thought of as functions, methods, or procedures that are internal to SQL Server.  They are written in TSQL but stored within SQL Server.  The first time a Stored Procedure is executed, SQL Server parses and compiles it, and stores the resultant Execution Plan in the Plan Cache.  The Execution Plan tells SQL Server how it is going to get the data to satisfy the request.

The reason you want to cache Query Plans is that if you run a query once, chances are you will run it again.  Some queries may run thousands of times during the course of a day.  It all depends upon the application.

Plan Cache

The Plan Cache is the area of memory where SQL Server stores the Execution Plans for any queries or stored procedures.  Compiling and caching the execution plan does take a few extra CPU cycles away from the server, so why would you do it?  The next time that query or stored procedure is run, SQL Server already knows how to get the data in an efficient manner.  As your application scales, and your query or stored procedure is being run hundreds or thousands of time, this helps the execution to be a fast as possible.

Single-Use Plans

The goal with caching Query Plans is for the execution count be as high as possible.  This means we are getting the most bang for our buck.  However, if you have lots of single-use plans, then you are wasting CPU cycles calculating the plans, and you are wasting memory by storing them.

Every CPU cycle that is wasted compiling and caching a single-use Query Plan is a CPU cycle that could have been doing some work for your application.  Every byte of memory that is wasted storing a single-use Query Plan is memory that could have been used somewhere else.

If you have a high number of single-use plans in your cache, this could be contributing to high CPU utilization, excessive IO, or low memory on your server.

How to Find Ad-hoc Queries and Single-Use Plans

One way to find out if you have ad-hoc queries hitting your database is to ask the development teams if they have any ad-hoc queries in their code.  There are a couple of problems with this approach.

For one, they may not be aware if they are using ad-hoc queries.  If you have a large application, each developer may only familiar with a small part of it.  Also, if you have inherited an existing application, it may be difficult or impossible to wrap your head around the entire code base.

Another scenario is that the developers may be aware of some of their ad-hoc queries, but may underestimate the number of times they are being called, or they may not realize the impact they have upon the system.

As better approach is to ask SQL Server to tell you what sort of plans it has cached.

sys.dm_exec_cached_plans

SQL Server provides us with a Dynamic Management View, sys.dm_exec_cached_plans which lists out every Execution Plan that is currently stored in the Query Cache.  At the most basic level, you can query this DMV to see the details on every Query Plan in your system.


-- basic query
select * from sys.dm_exec_cached_plans

By itself, this is not very useful. Of course, like all SQL queries you can add various WHERE clauses or aggregates in order to make it more meaningful for you.

So, how much are you wasting?

The way I approached this problem was to calculate how much memory the entire Plan Cache was using, then compare that to how much the Single-Use Adhoc Plans were using.  Once I had those numbers, I did some quick math to figure out what percentage of my Plan Cache was going to Single-Use Adhoc Plans.


-- check percentage of the plan cache that is wasted on single-use adhoc plans

-- use a CTE to check across multiple servers
-- horizontal formatting
-- all plans
;with all_plans as (
	select @@SERVERNAME as 'ServerName',
		COUNT(*) as 'All Plans Count',
		sum(cast(size_in_bytes as bigint)) / 1024 / 1024 as 'Total MB',
		avg(cast(size_in_bytes as bigint)) / 1024 as 'Average KB'
	from sys.dm_exec_cached_plans
),

-- adhoc plans
adhoc_plans as (
	select @@SERVERNAME as 'ServerName',
		COUNT(*) as 'Adhoc Plans Count',
		sum(cast(size_in_bytes as bigint)) / 1024 / 1024 as 'Total MB',
		avg(cast(size_in_bytes as bigint)) / 1024 as 'Average Bytes'
	from sys.dm_exec_cached_plans
	where objtype = 'Adhoc'
),

-- single-use adhoc plans
	single_adhoc as (
	select @@SERVERNAME as 'ServerName',
		COUNT(*) as 'Single-Use Adhoc Plans Count',
		sum(cast(size_in_bytes as bigint)) / 1024 / 1024 as 'Total MB',
		avg(cast(size_in_bytes as bigint)) / 1024 as 'Average Bytes'
	from sys.dm_exec_cached_plans
	where usecounts = 1
		and objtype = 'Adhoc'
)

-- query the CTEs

-- geek version, show all the data
select ap.[All Plans Count], ap.[Total MB], ap.[Average KB],
	ah.[Adhoc Plans Count], ah.[Total MB], ah.[Average Bytes],
	sa.[Single-Use Adhoc Plans Count], sa.[Total MB], sa.[Average Bytes],
	cast(cast(sa.[Total MB] as numeric) / cast(ap.[Total MB] as numeric) * 100 as numeric(5,2)) as 'Percent Wasted on Single-Use Adhoc Plans'
from all_plans ap
join adhoc_plans ah
on ap.ServerName = ah.ServerName
join single_adhoc sa
on ah.ServerName = sa.ServerName

I also have an Executive Version, which shows the Percentage Wasted without adding in all those confusing details.  Replace the Geek Version with this one when you query the CTEs.


-- executive summary, show how much memory is being wasted on single-use adhoc plans
select ap.[Total MB] as 'All Plans MB',
	sa.[Total MB] as 'Single-Use Adhoc MB',
	cast(cast(sa.[Total MB] as numeric) / cast(ap.[Total MB] as numeric) * 100 as numeric(5,2)) as 'Percent Wasted on Single-Use Adhoc Plans'
from all_plans ap
join adhoc_plans ah
on ap.ServerName = ah.ServerName
join single_adhoc sa
on ah.ServerName = sa.ServerName

Getting Buy In

If you encounter resistance to changing this setting, run this query against multiple servers and save the results in Excel.  Bosses love Excel; it helps them think.  🙂

Even better, write up a simple Word Document or PowerPoint Presentation and tie it back to the business or the budget.  That will make an impression.

How much did you spend on memory when you built the server?  Do you see evidence of memory pressure on your server?  Are some of your key business processes running slow because they are not able to get enough memory.

One technique I have used is to put your conclusion first.  Then, lead them along the path that led you to your conclusion.  Put in a few key graphs and screenshots, and voila!  Many managers will not read beyond the first slide or paragraph so you need to work on getting your core message conveyed in a very brief space.

How to fix it

The fix is quite simple: optimize for adhoc workloads.


-- show advanced options - enables all options to be seen / set
use [master]
go
exec sp_configure 'show advanced options', 1
go
reconfigure
go

-- check to see if it is turned on
sp_configure 'optimize for ad hoc workloads'
go

-- optimize for ad hoc workloads
sp_configure 'optimize for ad hoc workloads', 1
go
reconfigure
go

-- verify that it has been set correctly
sp_configure 'optimize for ad hoc workloads'
go

This is an Instance Level setting that tells SQL Server not to compile and cache the Query Plan the first time it encounters an Adhoc Query.  Instead, it compiles a Plan Stub.

The Plan Stub is a small identifier that allows SQL Server to recognize that a particular plan has been looked at before.  This way, if it does end up getting multiple uses down the road, SQL Server is able to compile and cache the plan as normal.

For many of my servers, the Plan Stub was an Order of Magnitude smaller than the size of the full Query Plan; 320 bytes versus 25,000k-35,000 bytes for the average Single-Use Adhoc Query Plan.  Of course, your mileage may vary.

Make it so, Number One!

Something to keep in mind, is that you will not be able to predict or control what SQL Server will decide to use its newfound memory on.  Kimberly Tripp (blog | twitter) has an excellent article which discusses some of the behaviors you may observe.

Conclusion

Taking a look inside your Plan Cache can be an illuminating experience.  While you may not get any money back, it is worth looking into.