Inicial > Não categorizado > Statistics used in a cached query plan

Statistics used in a cached query plan

Today I was working on the material for the on-demand (online) training we’ll offer in next few days at Sr.Nimbus when I find-out a very interesting thing.

“The statistics used in a query plan are stored in a cached execution plan, and you can see them using the special trace flag 8666 (there is always a traceflag).”

It is also possible to identify which statistics were used in a query plan compilation if you run the query using traceflags 9292 and 9204 as Query Optimizer Guru Paul White (blog|twitter) showed here.

What I’m saying is that you can also see in the XMLPlan the used statistics.

Let’s see a small sample of what I’m saying…

First let’s clear the cache plan memory area:

 1: DBCC FREEPROCCACHE()

Now let’s run a small query on the Northwind database:

 1: USE Northwind

 2: GO

 3: SELECT Employees.FirstName, COUNT(Orders.OrderID)

 4:   FROM Orders

 5:  INNER JOIN Employees

 6:     ON Orders.EmployeeID = Employees.EmployeeID

 7:  WHERE Employees.FirstName = 'Steven'

 8:  GROUP BY Employees.FirstName

 9: GO

This is the plan:

clip_image001

Running the same query with TF 8666 on, we’ve the following information in the xml query plan (right click in the select operator and select properties):

clip_image002

This new element InternalInfo in the XML plan is documented on the current schema http://schemas.microsoft.com/sqlserver/2004/07/showplan/showplanxml.xsd

The information we can see here are confuse and used by Microsoft people to debug query plans, but, one specific tag is more interesting than others… This is the ModTrackingInfo tag. There we can see the statistics used information, let’s dig in:

clip_image003

In the image above we can see two “Recompile” tags (collapsed), in fact we’ve one tag for each table in the query (in our sample, table orders and table employees).

clip_image004

Isn’t that nice or what?

Could be this be even more interesting? Yes.

All this information are also stored in the cached plans. That means if you query the Cached Plans DMVs with the TF turned on, we’ll be able to use xquery to query the used statistics.

For instance:

 1: DBCC TRACEON(8666)

 2: GO

 3: WITH XMLNAMESPACES ('http://schemas.microsoft.com/sqlserver/2004/07/showplan' as p)

 4: SELECT qt.text AS SQLCommand,

 5:        qp.query_plan,

 6:        StatsUsed.XMLCol.value('@FieldValue','NVarChar(500)') AS StatsName

 7: FROM sys.dm_exec_cached_plans cp

 8:     CROSS APPLY sys.dm_exec_query_plan(cp.plan_handle) qp

 9:     CROSS APPLY sys.dm_exec_sql_text (cp.plan_handle) qt

 10:     CROSS APPLY query_plan.nodes('//p:Field[@FieldName="wszStatName"]') StatsUsed(XMLCol)

 11:  WHERE qt.text LIKE '%Steven%'

 12:    AND qt.text NOT LIKE '%sys.%'

 13: GO

 14: DBCC TRACEOFF(8666)

 15: GO

Will Return:

clip_image001[6]

I’m sure you can do better xquery than I to query this from cacheplan.

Now the boring part of the this… First of all and the most important. This traceflag IS NOT DOCUMENTED so please be very very very careful to use it, and use only for tests purposes, never use it in a production environment. Also when I tried to use it on SQL Server 2008R2 sometimes I’ve got nasty errors generating dump and closing my session.

Since I‘m aware, it works fine on SQL Server 2012, at least I didn’t received any error on using it.

Let me know if you try it on an SQL 2005 instance… And also about bugs and discovers you may find with it Smile.

Happy query.

Categorias:Não categorizado
  1. Jeff Moden
    18 de setembro de 2016 às 17:11

    Thought I’d drop a note to thank you for this article. I’m using 2012 and have turned Trace Flag 8666 on as a part of the startup for my main server about 2 months ago with no ill effects.

    The folks before me had a “stats maintenance” job that would automatically create column stats for every column in every table in every database the code was played against. On just 5 of the main databases, it takes over 17 hours to update the stats on just 5 of my main databases.

    You’re good code takes about 10 minutes to run on my main “money maker” database and it’s going to be worth every second. I have personal experience as to what can happen even overnight with stats that haven’t been updated for the latest load on some of my larger, super wide tables (no my fault ;-)) and have found that nightly stats maintenance (sometimes right after a large load that doesn’t trigger auto-updates, as well) are even more important than fragmentation (sidebar… haven’t done ANY index maintenance since 17 Jan 2016 based on a suggestion by Brent Ozar and related info by Kendra Little and performance has improved across the board by ~10% and blocking has virtually vanished).

    To wit, your good code will figure prominently in the stats maintenance code I’m writing for the company I work for. I may also write an article on what I’ve done and I’ll be sure to provide a link and credits to this wonderful article of yours.

    Thanks again for the time you spent researching and publishing this post.

    –Jeff Moden
    Fellow SQL Server MVP

    • 21 de setembro de 2016 às 12:57

      This is awesome … thanks for the feedback Jeff.

      Regards
      Fabiano

  2. Matthew McGiffen
    15 de dezembro de 2016 às 10:04

    Hi Fabiano,

    Thanks for the post, I’ve been looking for a way of doing this recently and came across your blog. I’ve just been testing this across SQL versions, I can confirm 8666 works from SQL 2008 through to 2016 – but not on SQL 2005 (for me anyway).

    Cheers,

    Matthew.

  1. 3 de julho de 2012 às 19:13
  2. 1 de novembro de 2012 às 22:22
  3. 27 de novembro de 2012 às 23:49
  4. 4 de janeiro de 2013 às 13:07
  5. 4 de janeiro de 2013 às 13:36
  6. 14 de maio de 2014 às 8:10
  7. 4 de novembro de 2014 às 10:58
  8. 3 de março de 2015 às 20:08
  9. 13 de abril de 2017 às 13:20
  10. 27 de julho de 2017 às 18:36
  11. 8 de janeiro de 2018 às 13:11
  12. 11 de janeiro de 2018 às 11:00
  13. 26 de fevereiro de 2018 às 10:52
  14. 12 de setembro de 2021 às 2:40

Deixe um comentário