Low Procedure Cache Hit Rate means no use of stored procedures?

  • Hi everyone. I'm not really understanding how the procedure cache works in SQL Server 2008 R2.

    I have 100GB ram allocated to SQL Server. Of the 100GB ram, 8.30 GB is allocated to the procedure cache. Spotlight on SQL Server Enterprise is telling me that the hit rate is 59.2%. The recompile rate is near zero.

    When I query the procedure cache, there are only three plans from the application that are being stored. Two triggers ad one proc. The rest are maintenance tasks from msdb. The application is very busy 24/7 so I'm wondering why the procedure cache is not full. Profiler trace of cache insert shows constant inserts of select queries. Everything from simple select * from <table> to more complex selects with multiple joins.

    I'm wondering if this means that the application has to compile every query that hits it because the application does not use stored procedures with parameters. I wonder how inefficient that is and if there is anything that can be done.

    Thanks for reading and helping me to understand.

    Howard

  • As I dig deeper into the trace output, the selects are all under SQL:Batch and the inserts and updates come through RPC exec sp_executesql N'DELETE FROM.......' <p1 value>,<p2 value>

    Does that make sense? Does it need to make a new execution plan each time the nonstop selects are happening? I see a new cache insert after each select. How about the sp_execute? Does that make a new plan each time? How does it all affect performance?

  • I changed the advanced settings to optimize for ad hoc workloads and now the cache is much smaller but I don't expect the hit rate to go up since very few of the query plans are being reused.

  • Looking at a few rows of the procedure cache, I see this:

    UseCountsRefCountsCacheobjtypeObjtypedbidSQLSTMT

    11Compiled Plan StubAdhocNULLSELECT * FROM dbo.REFER WHERE USERID = 186 AND MSGID = 296

    11Compiled Plan StubAdhocNULLSELECT * FROM dbo.REFER WHERE USERID = 209 AND MSGID = 162

    11Compiled Plan StubAdhocNULLSELECT * FROM dbo.REFER WHERE USERID = 131 AND MSGID = 294

    11Compiled Plan StubAdhocNULLSELECT * FROM dbo.REFER WHERE USERID = 210 AND MSGID = 359

    11Compiled Plan StubAdhocNULLSELECT * FROM dbo.REFER WHERE USERID = 182 AND MSGID = 280

    11Compiled Plan StubAdhocNULLSELECT * FROM dbo.REFER WHERE USERID = 189 AND MSGID = 358

    etc etc etc

    It is the same query over and over. Why would it not reuse the compiled plan?

  • Would there be a benefit to using forced parameterization if the procedure cache is filled up with hundreds of these plan stubs and not much else?

    If I could get the procedure cache hit rate up, I'd be thrilled.

  • So I did a little bit of poking around and found that the procedure cache is filled with about 70,000 rows with one execution each of the above select query and very few other things.

    Is that because it is considered trivial? Set stat time on shows compilation at 0ms so I wonder if there would be any benefit to forced parameterization.

  • Hi everyone. I added a plan guide.

    DECLARE @stmt nvarchar(max);

    DECLARE @params nvarchar(max);

    EXEC sp_get_query_template

    N'SELECT * FROM dbo.REFER WHERE USERID = 619 AND MSGID = 104',

    @stmt OUTPUT,

    @params OUTPUT;

    EXEC sp_create_plan_guide

    N'TemplateGuide1',

    @stmt,

    N'TEMPLATE',

    NULL,

    @params,

    N'OPTION(PARAMETERIZATION FORCED)';

    Within seconds there were thousands and thousands of executions using the parameterized query plan instead of thousands of single use adhoc plan stubs for the same query.

    I don't know if it is a performance increase or not. Hope so!

  • If you have lots of ad hoc queries, it's not a surprise that your procedure cache hit rate is low. As a matter of fact, that would be normal. Optimize for ad hoc is a good choice. Going past simple parameterization to forced might be helpful and it might not. Even with plan guides, you'll want to test performance.

    I wouldn't focus too much on the procedure cache hit ratio. It's a weak measure of performance. It does give you some indicators, but not enough to know you have real problems. Better to focus on wait statistics and actual query execution time.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Adding the plan guide for that one query has changed the hit rate from 60% to 99%.

    I don't know if it made a performance difference though because the query plan was probably trivial but it does look better on my diagnostic screen now.

Viewing 9 posts - 1 through 8 (of 8 total)

You must be logged in to reply to this topic. Login to reply