Spell It Out
Back in October, I had written a couple posts about how parameterizing TOP can cause performance issues:
Anyway, I got back to thinking about it recently because a couple things had jogged in my foggy brain around table valued functions and parameter sniffing.
Go figure.
Reading Rainbow
One technique you could use to avoid this would be to use an inline table valued function, like so:
CREATE OR ALTER FUNCTION dbo.TopParam(@Top bigint) RETURNS TABLE WITH SCHEMABINDING AS RETURN SELECT TOP (@Top) u.DisplayName, b.Name FROM dbo.Users AS u CROSS APPLY ( SELECT TOP (1) b.Name FROM dbo.Badges AS b WHERE b.UserId = u.Id ORDER BY b.Date DESC ) AS b WHERE u.Reputation > 10000 ORDER BY u.Reputation DESC; GO
When we select from the function, the top parameter is interpreted as a literal.
SELECT tp.* FROM dbo.TopParam(1) AS tp; SELECT tp.* FROM dbo.TopParam(38) AS tp;
Performance is “fine” for both in that neither one takes over a minute to run. Good good.
Departures
This is, of course, not what happens in a stored procedure or parameterized dynamic SQL.
EXEC dbo.ParameterTop @Top = 1;
Keen observers will note that this query runs for 1.2 seconds, just like the plan for the function above.
That is, of course, because this is the stored procedure’s first execution. The @Top
parameter has been sniffed, and things have been optimized for the sniffed value.
If we turn around and execute it for 38 rows right after, we’ll get the “fine” performance noted above.
EXEC dbo.ParameterTop @Top = 38;
Looking at the plan in a slightly different way, here’s what the Top operator is telling us, along with what the compile and runtime values in the plan are:
It may make sense to make an effort to cache a plan with @Top = 1
initially to get the “fine” performance. That estimate is good enough to get us back to sending the buffers quickly.
Buggers
Unfortunately, putting the inline table valued function inside the stored procedure doesn’t offer us any benefit.
Without belaboring the point too much:
CREATE PROCEDURE dbo.ParameterTopItvf(@Top BIGINT) AS BEGIN SET NOCOUNT, XACT_ABORT ON; SELECT tp.* FROM dbo.TopParam(@Top) AS tp; END; GO EXEC dbo.ParameterTopItvf @Top = 1; EXEC dbo.ParameterTopItvf @Top = 38; EXEC sp_recompile 'dbo.ParameterTopItvf'; EXEC dbo.ParameterTopItvf @Top = 38; EXEC dbo.ParameterTopItvf @Top = 1;
If we do this, running for 1 first gives us “fine” performance, but running for 38 first gives us the much worse performance.
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
- Defeating Parameter Sniffing With Dynamic SQL In SQL Server
- SQL Server 2017 CU 30: The Real Story With SelOnSeqPrj Fixes
- SQL Server 2017 CU 30 Doesn’t Actually Fix The Problem With Views And Parameters
- SQL Server 2022 Parameter Sensitive Plan Optimization: The Problem With Sniffed Parameter Sensitivity