DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports
Events Video Library
Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
View Events Video Library
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

Integrating PostgreSQL Databases with ANF: Join this workshop to learn how to create a PostgreSQL server using Instaclustr’s managed service

Mobile Database Essentials: Assess data needs, storage requirements, and more when leveraging databases for cloud and edge applications.

Monitoring and Observability for LLMs: Datadog and Google Cloud discuss how to achieve optimal AI model performance.

Automated Testing: The latest on architecture, TDD, and the benefits of AI and low-code tools.

Related

  • A New Era Has Come, and So Must Your Database Observability
  • Conversational Applications With Large Language Models Understanding the Sequence of User Inputs, Prompts, and Responses
  • Automating Database Operations With Ansible and DbVisualizer
  • Database Monitoring: Key Metrics and Considerations

Trending

  • Microservices With Apache Camel and Quarkus (Part 5)
  • Generative AI: A New Tool in the Developer Toolbox
  • Database Monitoring: Key Metrics and Considerations
  • Best Practices for Writing Clean Java Code
  1. DZone
  2. Data Engineering
  3. Databases
  4. Get the Last Actual Plan With sys.dm_exec_query_plan_stats

Get the Last Actual Plan With sys.dm_exec_query_plan_stats

Let's check out the last actual plan with sys.dm_exec_query_plan_stats.

Grant Fritchey user avatar by
Grant Fritchey
·
Oct. 08, 19 · Review
Like (2)
Save
Tweet
Share
8.15K Views

Join the DZone community and get the full member experience.

Join For Free

Image title

Last plan with sys.dm_exec_query_plan_stats

I've always felt responsible for making such a big deal about the differences between estimated and actual plans. I implied in the first edition of the execution plans book (get the new, vastly improved, 3rd edition in digital form for free here, or you can pay for the print version) that these things were so radically different that the estimated plan was useless. This is false. All plans are estimated plans. However, actual plans have some added runtime metrics.

It's not that we're going to get a completely different execution plan when we look at an actual plan, it's just going to have those very valuable runtime metrics. The problem with getting those metrics is you have to execute the query. However, this is no longer true in SQL Server 2019 (CTP 2.4 and greater) thanks to sys.dm_exec_query_plan_stats.

You might also enjoy:  Better SQL Server CPU Defaults in 2019

Lightweight Statistics

It all starts with a new database scoped configuration LAST_QUERY_PLAN_STATS, or, if you like, you can turn it on at the server level using a trace flag, 2451. I prefer the more granular control, especially because, while we will be adding an extremely lightweight additional load to the server, we're adding additional load to the server.

I'd rather pick and choose which databases it gets applied to in order to minimize that load as much as is reasonable, while still absolutely taking advantage of this new functionality. In my testing (little so far), I didn't see this affect the server at all, however, being conservative on things like this is generally a good approach:

ALTER DATABASE SCOPED CONFIGURATION SET LAST_QUERY_PLAN_STATS = ON;

sys.dm_exec_query_plan_stats

Once you've enabled the collection through the trace flag or the database configuration, you'll begin to see data collected in the DMV. Querying it can be quite simple. Here, I combine it with sys.dm_exec_procedure_stats:

SELECT deqps.query_plan
FROM sys.dm_exec_procedure_stats AS deps
    CROSS APPLY sys.dm_exec_query_plan_stats(deps.plan_handle) AS deqps
WHERE deps.object_id = OBJECT_ID('dbo.AddressByCity');

The result set is a single execution plan in XML format (no cast involved, which, possibly means that plans that exceed the XML nesting limit won't be shown here?) that you can click on:


That, dear friends, is an actual execution plan, the last one run on the system. Because you see the row counts, you know this is an actual plan. I can get this plan with the runtime metrics without having to execute the query. That's pretty huge.

Conclusion

Please let me reiterate. All plans are estimated plans. You can get an estimated plan with runtime metrics. This is what we call an "actual" plan. Just remember that these are the same as estimated plans. However, what makes them so very attractive are the runtime metrics. Now, in SQL Server 2019, we can get these runtime metrics without having to execute a query. That's a win!

Further Reading

SQL Server Containers Are Boring

Entity Framework Core 3.0 and SQL Server Performance Optimization, Part 1: Parameters Sniffing

Database

Published at DZone with permission of Grant Fritchey, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Related

  • A New Era Has Come, and So Must Your Database Observability
  • Conversational Applications With Large Language Models Understanding the Sequence of User Inputs, Prompts, and Responses
  • Automating Database Operations With Ansible and DbVisualizer
  • Database Monitoring: Key Metrics and Considerations

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • support@dzone.com

Let's be friends: