Quiet As Kept
I’ve been trying to take the general temperature when it comes to SQL Server 2022. At least from a performance perspective, some interesting things have been introduced so far.
There have been a few neat things:
- Parameter Sensitive Plan optimizations
- Query Store Hints
- Memory Grant Feedback improvements
- DOP Feedback
- Cardinality Estimation Feedback
I’m not seeing a whole lot out there. I’m not sure why. I follow quite a few SQL bloggers via Feedly.
Perhaps it’s just too new. Maybe everyone is waiting for CTP SP1.
Well, anyway. In this post I want to talk a little bit about what Cardinality Estimation Feedback can do, and what it can’t do.
What It Do
First, you need Query Store enabled to get this to work. It relies on the Query Store Plan hints also introduced for SQL Server 2022.
For queries that execute frequently and retain cached plans, the optimizer will look at some of the assumptions that get made under different Cardinality Estimation models.
Things like:
- Row Goals
- Predicate independence/correlation
- Join containment being simple or base
What each of those things means isn’t terribly important to the post, but all of them are things that are influenced by using the legacy or default cardinality estimators.
As I understand it, this is a bit like Memory Grant Feedback. If estimation issues are detected, a different plan will be attempted. If that plan corrects a performance issue, then the hint will get persisted in Query Store.
Pretty cool, but…
What It Don’t Do
It doesn’t fix things while they’re running, like Adaptive Joins can do. That’s sort of unfortunate! Hear me out on why.
Often, when model errors are incorrect, queries run for a long time. Particularly when row goals are introduced, query plans are quite sensitive to those goals not being met quickly.
It’d be really unfortunate for you to sit around waiting for 15-16 executions of a poor performing query to finish executing before an intervention happens.
I would have either:
- Reduced, or made this threshold configurable
- Been more aggressive about introducing Adaptive Joins when CE models influence plan choices
After all, Adaptive Joins help queries at runtime rather than waiting for an arbitrary number of executions and then stepping in.
Perhaps there was a good reason for not doing this, but those were the first two things to cross my mind when looking into the feature.
How It Do
I was able to get the feature to kick in using a familiar query.
Here’s the setup script:
DBCC FREEPROCCACHE; ALTER DATABASE StackOverflow2010 SET QUERY_STORE CLEAR; GO CREATE INDEX whatever ON dbo.Votes(CreationDate, VoteTypeId, PostId); CREATE INDEX apathy ON dbo.Posts (PostTypeId) INCLUDE (OwnerUserId, Score, Title); GO SELECT TOP (2500) p.OwnerUserId, p.Score, p.Title, v.CreationDate, ISNULL(v.BountyAmount, 0) AS BountyAmount FROM dbo.Posts AS p JOIN dbo.Votes AS v ON p.Id = v.PostId WHERE v.VoteTypeId = 1 AND p.PostTypeId = 1 ORDER BY v.CreationDate DESC; GO 17 SELECT qspf.* FROM sys.query_store_plan_feedback AS qspf; SELECT qsqh.* FROM sys.query_store_query_hints AS qsqh;
For the first 16 runs, we get the same query plan that takes about 2 seconds.
Then, magically, on run #17, we get a different query plan!
Pretty cool! The plan totally changed, and clearly got better. I am happy about this. Not so happy that it would have taken 16 executions of a Potentially Painful© query to get here, but you know.
Here we are.
In Query Store
There are a couple views that will detail where hints came from and which were applied:
Since I just cleared out query store prior to this running, we can infer some things:
- CE Feedback kicked in and gave us a new plan with a hint to disable row goals
- The second plan generated was identified by the engine as needing memory grant feedback
I suppose this is a good reason to do some work on sp_QuickieStore so y’all can see this stuff in action.
Thanks for reading!
Going Further
If this is the kind of SQL Server stuff you love learning about, you’ll love my training. I’m offering a 75% discount to my blog readers if you click from here. I’m also available for consulting if you just don’t have time for that and need to solve performance problems quickly.
Related Posts
- How To Find Poorly Performing SQL Server Queries To Tune Using Query Store
- SQL Server 2022 CTP 2.1 Improvements To Parameter Sensitive Plan Optimization
- SQL Server 2022: Introduces the DATETRUNC Function, So You Can Truncate Your Dates And Stuff
- How SQL Server 2022’s Parameter Sensitive Plan Feature Can Make Query Store Confusing
>There are a couple views that will detail where hints came from and which were applied
Can you share which views these are? Thanks!
I wonder if this feature might become more real time in the SQL Server version after 2022, and they were just doing the “minimum viable product” thing here or whether they are trying to eliminate the plan thrashing that can occur when they only look at the current vs. previous plan without considering a bit more history for things like memory grants. It would be great if they might explain their intent with this feature and its potential future.
Mark, they’re in the post.
D’oh! Hiding in plain sight in the script. Sorry!