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


TSQL Short Circuiting


TSQL Short Circuiting

Author
Message
Adam Parrott
Adam Parrott
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 1
I am trying to short circuit some code to help optimize a query and also to build a dynamic where clause. When I view The Query Execution in QA however the code that should not get executed gets executed anyway. Is there any way to force a short circuit?

My where clause consists of:

WHERE r.loc_isActive = 1 AND
r.hidden = 0 AND
( @adminSearch = 1 OR r.completedStep >= 4 ) AND
( @adminSearch = 1 OR r.searchable = 1 ) AND
( @adminSearch = 1 OR NOT EXISTS (SELECT * FROM [dbo].[UserLabels] WHERE userID = r.userID AND labelID = 5) ) AND
( @labelID = 0 OR EXISTS (SELECT * FROM [dbo].[UserLabels] WHERE userID = r.userID AND labelID = @labelID) )

In this example the parameter @labelID is indeed 0 but SQL Server still executes the EXISTS (SELECT * FROM [dbo].[UserLabels] WHERE userID = r.userID AND labelID = @labelID). It doesn't return the results from it so in that case the Short circuit works but the Execution Plan still shows it executing thus degrading the performance of the query when it is not necessary.
Rob Farley
Rob Farley
Old Hand
Old Hand (348 reputation)Old Hand (348 reputation)Old Hand (348 reputation)Old Hand (348 reputation)Old Hand (348 reputation)Old Hand (348 reputation)Old Hand (348 reputation)Old Hand (348 reputation)

Group: General Forum Members
Points: 348 Visits: 375
Use a 'case' statement. That will stop the rest being executed. I've used '1=1' and '1=0' for the true and false scenarios. Check the logic of course... I didn't really pay much attention to it.

where r.loc_isactive = 1
and r.hidden = 0
and 1= case when @adminSearch = 1 then 1
when NOT r.completedStep >= 4 then 0
when NOT r.searchable = 1 then 0
when EXISTS (SELECT * FROM [dbo].[UserLabels] WHERE userID = r.userID AND labelID = 5) then 0
else 1 end
and 1= case when @labelID=0 then 1
when EXISTS (SELECT * FROM [dbo].[UserLabels] WHERE userID = r.userID AND labelID = @labelID) then 1
else 0 end

Rob

Rob Farley
LobsterPot Solutions & Adelaide SQL Server User Group
Company: http://www.lobsterpot.com.au
Blog: http://sqlblog.com/blogs/rob_farley
Bart Duncan
Bart Duncan
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 21
Be ware that even CASE does not always provide deterministic order of evaluation with short circuiting. See http://bartduncansql.wordpress.com/2011/03/03/dont-depend-on-expression-short-circuiting-in-t-sql-not-even-with-case/. (It'll probably work for the example shown above, but be aware that this depends on undocumented behavior that is subject to change.)
Bart Duncan
Bart Duncan
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 21
Update: that exception to normal T-SQL CASE short circuiting should be fixed in an upcoming SQL release, per the Connect bug. It's still the behavior in SQL2005-SQL2008R2 (and maybe SQL2000), so keep an eye out for it as you use CASE for short-circuiting in existing releases.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search