Lavender
If you ask people who tune queries why batch mode is often much more efficient with windowing functions, they’ll tell you about the window aggregate operator.
That’s all well and good, but there’s another, often sneaky limitation of fully row mode execution plans with windowing functions.
Let’s go take a look!
Global Aggregates
One thing that causes an early serial zone in execution plans is if you use a windowing function that only has the order by
For example, let’s look at the plans for these two queries:
WITH Comments AS ( SELECT ROW_NUMBER() OVER(ORDER BY c.CreationDate) AS n FROM dbo.Comments AS c ) SELECT * FROM Comments AS c WHERE c.n = 0; WITH Comments AS ( SELECT ROW_NUMBER() OVER(PARTITION BY c.UserId ORDER BY c.CreationDate) AS n FROM dbo.Comments AS c ) SELECT * FROM Comments AS c WHERE c.n = 0;
The resulting estimated plans look like this, using the 140 compatibility level:
In the top plan, where the windowing function only has an order by, the serial zone happens immediately before the Segment operator. In the second plan, the parallel zone carries on until right before the select operator.
If you’re wondering why we’re only looking at estimated plans here, it’s because repartition streams ruins everything.
In The Year 2000
In compatibility level 150, things change a bit (yes, a window aggregate appears):
And the window aggregate appears within the parallel zone. The parallel zone does end before the filter operator, which may or may not be a disaster depending on how restrictive your filter is, and how many rows end up at it.
Also note the distinct lack of a repartition streams operator ruining everything. We’ll talk about that tomorrow.
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
- Getting The Top Value Per Group With Multiple Conditions In SQL Server: Row Number vs. Cross Apply With MAX
- Getting The Top Value Per Group In SQL Server: Row Number vs. Cross Apply Performance
- Multiple Distinct Aggregates: Still Harm Performance Without Batch Mode In SQL Server
- Database Context Is Everything In SQL Server
One thought on “An Overlooked Benefit Of Batch Mode With Windowing Functions In SQL Server”
Comments are closed.