SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 

Parameterized dynamic SQL is parameterized.

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. 

Variable version:

Parameter version:

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.

SQLStudies

My name is Kenneth Fisher and I am Senior DBA for a large (multi-national) insurance company. I have been working with databases for over 20 years starting with Clarion and Foxpro. I’ve been working with SQL Server for 12 years but have only really started “studying” the subject for the last 3. I don’t have any real "specialities" but I enjoy trouble shooting and teaching. Thus far I’ve earned by MCITP Database Administrator 2008, MCTS Database Administrator 2005, and MCTS Database Developer 2008. I’m currently studying for my MCITP Database Developer 2008 and should start in on the 2012 exams next year. My blog is at www.sqlstudies.com.

Comments

Leave a comment on the original post [sqlstudies.com, opens in a new window]

Loading comments...