Data About Execution Plans

If you look at the Properties for the first operator of a graphical execution plan, you get all sorts of great information. I’ve talked about the data available there and how important it is in this older post. Checking out the properties of a plan you’re working on is a fundamental part of tuning that plan. What happens when you don’t know which plan you should be working on? What do you do, for example, if you want to see all the plans that are currently using ARITHABORT=FALSE or some other plan affecting setting?

The “easy” answer to this question is to run an XQuery against the XML of the query plan itself. You can identify these properties and retrieve the appropriate values from within the plan. However, XQuery consumes quite a bit of resources and you might not want to run this on a production system that’s already under stress. Now what?

sys.dm_exec_plan_attributes

There is a DMV that isn’t used a lot of the time because the information within it frequently doesn’t have a lot of bearing on solving fundamental query tuning issues such as out of date statistics, bad or missing indexes, or poorly structured T-SQL. This DMV, sys.dm_exec_plan_attributes, contains a bunch of values that are used by the optimizer to identify a plan in cache, such as object_id (if any), database_id, and compatibility level (compat_level). In addition to these clear & easy to understand attributes, there’s one more, set_options, that’s not immediately clear.

set_options

Follow the link about and you’ll find that the set_options column is a bitmask. It contains a number of settings within a single value. I won’t argue that this is a good (or bad) design. That’s what it is. The question is, how do we use it? Here’s a simple query that shows all the queries that have ANSI_WARNINGS set to true:

SELECT detqp.query_plan,
       depa.attribute,
       depa.value
FROM sys.dm_exec_query_stats AS deqs
CROSS APPLY sys.dm_exec_text_query_plan(
                                          deqs.plan_handle,
                                          deqs.statement_start_offset,
                                          deqs.statement_end_offset
                                       ) AS detqp
CROSS APPLY sys.dm_exec_plan_attributes(deqs.plan_handle) AS depa
WHERE depa.attribute = 'set_options'
      AND (CAST(depa.value AS INT) & 16) = 16;

If you were looking for queries that didn’t have ANSI_WARNINGS, you could just change the value to 0. Use the values from the documentation link above to look at the various settings based on their bit values.

NOTE: One of the values is ‘Parallel’. When I was investigating this, I became very excited that this would be a way to programmatically identify parallel execution plans. However, it’s an attribute, like that others, that determines how a plan can be, not is, compiled. So looking at the parallel value here would just mean that a given plan could be parallel, not that it is.

Conclusion

You don’t want to be completely dependent on the query plan when it comes to investigation and identifying queries with problems. Instead, you want to be systematic in the approach. Using sys.dm_exec_plan_attributes, you can query for information about your queries.

 

4 thoughts on “Data About Execution Plans

Please let me know what you think about this article or any questions:

This site uses Akismet to reduce spam. Learn how your comment data is processed.