Parameterized dynamic SQL is parameterized.
3November 15, 2018 by Kenneth Fisher
Ok, that title sounds silly, but it’s actually a real point. The first parameterized refers to using parameters within dynamic SQL, while the second refers to how the optimizer treats parameters differently from variables. When you use parameterized dynamic SQL with sp_executesql SQL server treats the parameters as actual parameters not variables. As with all things, an example would probably help here.
-- Setup SELECT * INTO myColumns FROM sys.all_columns ALTER TABLE myColumns ADD CONSTRAINT pk_myColumns PRIMARY KEY (object_id, column_id) CREATE INDEX ix_myColumns ON myColumns (name)
I’m using a very simple table, taking the data from sys.all_columns, with a pretty basic clustered primary key and index.
-- Code DECLARE @name varchar(50) = 'name' SELECT * FROM myColumns WHERE name = @name DECLARE @sql nvarchar(1000) = 'SELECT * FROM myColumns WHERE name = @name' EXEC sp_executesql @sql, N'@name varchar(50)', @name
The query plan for the first query
The query plan for the second query
What’s the difference?! Well, when you use a variable the optimizer uses an average value for the estimated number of rows (this is my best understanding and I could be miss-representing what’s actually happening but I don’t think so). When you use a parameter the optimizer can actually check the histogram and give an estimate based on the contents of the parameter. Here are the estimated and actual number of rows for each.
You’ll notice that the parameter version has a much closer (exact even) estimate of the number of rows.
Also if you look at the query plans you’ll see that the variable version shows as a smaller part of the plan (7%/93%), and yet, when I timed them they were pretty close on time (590ms/731ms). I mention this not because the variable version is normally faster, but because I want to point out that these are estimates, and not necessarily all that accurate.
Hi Kenneth, the issue you are describing is called ‘Parameter Sniffing’.
In your first example, the entire batch is optimized including the declare and SELECT, and therefore the optimizer is unaware of the actual value of the variable assignment at compile and optimize time. It has no choice but to use the density vector instead of the histogram as you correctly stated.
With sp_executesql, the SELECT statement executes in a sub scope, and the parameter can be ‘sniffed’ for optimization.
You can work around the first ‘anomaly’ by adding a WITH RECOMPILE hint, which will force a recompilation of the statement at run time, when the variable value is known, allowing the optimizer to consult the histogram.
Yep 🙂 I agree with all of the above. I was aware that it was called “parameter sniffing” but that wasn’t really the focus of the post. I was trying to point out that variables in the first example are not parameters and are not treated as parameters. Thus they can not be sniffed. In the sp_executesql example they ARE parameters and so can be sniffed. I’ve found that a lot of people either just see them as variables or don’t understand the difference.
👍