Query Store Questions: 24HOP follow up

 

A couple weeks ago I presented for the 24HOP Summit Preview and I had a lot of great general questions about how Query Store works.  My session title was “Why You Need Query Store” (you can watch it here) and I only had about 45 minutes.  As you can probably guess – since I have a full day pre-con on the topic – I can talk about Query Store for a loooong time 🙂  The 24HOP session was really focused on getting folks to understand THE most important things that Query Store provides to show why it’s needed.  I left out a lot of details about HOW Query Store works because talking through it is the fun stuff that I’ll dive into during the pre-con.  I did have a good number of questions from attendees related to specific functionality, and I promised to write a post answering them.  Questions* and answers are below…if you need clarification on anything, please leave a comment and I’ll follow up!

*Questions copied exactly as they were shared with me, I did not try to re-word or make any inferences about what was being asked.

Questions

1. Can I get Query Store data for a production database deployed on a client site, that I don’t actually have access to myself? Can the DBA send me something I can use in my own development environment?

A: You provide instructions to the client that explain how to enable Query Store, either through the UI or with T-SQL.  If you want to view that Query Store data, the client can either send you a backup of the database or create a clone with DBCC CLONEDATABASE and share that.

 

2. If a user executes a stored procedure from ‘master’ it is not captured?

A: If you have Query Store enabled for a user database, and you execute a query against that user database from the context of the master database, it is not supposed to be captured in Query Store for that user database.  But in my testing, it is.  But it is not supposed to be, so there is no guarantee it will always work that way.

 

3. If your database is part of an AG the data you look at can be different based on the server it is running on at that time, correct?

A: I’m not quite clear what’s being asked, but I wrote a post about Query Store and Availability Groups, which will hopefully answer the question.

 

4. Is it easy to remove the forcing of a given plan?

A: Yes, just use the “Unforce Plan” button in the UI, or use the stored procedure sp_query_store_unforce_plan (you supply the query_id and plan_id).

 

5. If you have 3+ plans how does SQL Server decide which plan to use?

A: I assume this is specific to the Automatic Plan Correction feature, and if so, it will force the last good plan (most recent plan that performed better than the current plan).  More details in my Automatic Plan Correction in SQL Server post.

 

6. What equivalent options we have for lower versions?

A:  There is an open-source tool called Open Query Store for versions prior to SQL Server 2016.

 

7. Why are the trace flags not on by default? given the issues with AlwaysOn and QS

A: Great question.  Trace flag 7752 will be default functionality in SQL Server 2019.  TF 7745 is not default functionality because, I suspect, of the potential for losing Query Store data…and SQL Server wants you to make a conscious choice about that.  More details in Query Store Trace Flags.

 

8. How would you use Query Store to troubleshoot Views?

A: Query Store does not differentiate between a query that references a view and a query that references a table.  It does not capture the object_id of the view and store that in Query Store (as happens for a stored procedure), so you have to look specifically for the view name in the query_sql_text column (within sys.query_store_query_text) to look for queries that reference the view.

 

9. Is there any way to make use of Query Store in readonly secondary AG replicas?

A: You can read data from the Query Store views on a read-only replica, but you cannot capture data in Query Store about queries executing against the read-only replica.  See my post referenced in #3, and then please up-vote this request: Enable Query Store for collection on a read-only replica in an Availability Group.

 

10. Is it possible that a query store run from one instance to another instance for example I want check the queries of production from dev instance?

A: If you can connect to the production instance from the dev instance, and have appropriate permissions, then you can query the Query Store data on the production instance (but the data exist in the production database).

 

11. If I execute a parameterized query with OPTION (RECOMPILE), will Query Store have the parameter values of every execution?

A: No.  The plan will have the values used for the initial execution that generated said plan, but values for every individual execution are not captured (it would generate excessive overhead to capture every execution).

 

12. Can Query Store supply the T-SQL to force plan?

A: The UI does not provide an option to script forcing a plan for a query, but if you are using Automatic Plan Correction, the T-SQL to force it can be found in sys.dm_db_tuning_recommendations.

 

13. Will there be any significant performance overhead by using query store?

A: See Query Store Performance Overhead: What you need to know

 

14. How does it function when queries span multiple databases?

A: As alluded to in question #2, cross-database queries are tricky.  You should work under the assumption that if you execute a query from Database_A, where Database_A has Query Store enabled, it will be captured.  If you execute a query from Database_A that queries both Database_A and Database_B, and both databases have Query Store enabled, it will ONLY be captured in Database_A.

 

15. It seems to be working for me, but sometimes not

A: I would love to help you out, just not sure of the behavior you’re seeing and what your question is.

 

16. How do you get the full query text from inside the ‘Top Resource Consuming Queries’ windows?

A: Click on the button with the grid and magnifying glass, which says “View the query text of the selected query in a query editor window” when you hover over it.

Button to display query text to help understand how query store works
Button to “View the query text of the selected query in a query editor window”

 

17. Is the data will be stored in Query Store After the adhoc/SP completed or it will do while is running?

A: Once the plan has been compiled for a query, the query text and plan are sent to Query Store.  When execution completes, the runtime statistics are sent to Query Store.

 

18. If we change the compatibility to SQL 2012 or lower, will that affect Query store?

A: No, Query Store functions in SQL Server 2016 and higher, and Azure SQL Database, regardless of your compatibility mode.

 

19. If we drop a SP, will that clear the history of that SP plans in the query store?

A: No, but…If you use DROP PROCEDURE syntax, then the object_id column in sys.query_store_query will no longer reference an existing object (in sys.objects).  The query and plans will stay in Query Store until they are aged out based on the retention policy.

 

Follow Up

Again, if any answers are unclear, leave a comment and I can clarify.  If you are interested in learning more about Query Store I would love to see you in my full day session at the PASS Summit!  It’s on Monday, November 5th, and you get more details here: Performance Tuning with Query Store in SQL Server

Leave a Reply

Your email address will not be published. Required fields are marked *

Other articles

A Fond Farewell

If you haven’t guessed from the title, I’m writing this post because I am leaving SQLskills. This Friday, January 14th, is my last day, and

Explore

Imagine feeling confident enough to handle whatever your database throws at you.

With training and consulting from SQLskills, you’ll be able to solve big problems, elevate your team’s capacity, and take control of your data career.