December 1, 2009 at 2:56 pm
Hi,
I have a situation where i have to execute either of the
below two select's based on a parameter.
If @VarName = 'Red', first query has to be executed else second query.
--Declare @VarName varchar(40)
select col1,col2
from Table
where col3 = 'Red'
select col1,col2
from Table
where col3 <> 'Red'
Any thoughts on this please.
Thanks,
December 1, 2009 at 3:15 pm
Try this
declare @Color varchar(10)
Set @Color = 'yellow'
;
with redcte as (select 'red' as one,'red' as two,'red' as three from sys.tables
union all
select 'yellow' as one,'yellow' as two,'yellow' as three from sys.tables)
select one,two from redcte
where three like (case @Color when 'red' then 'red' else @Color end)
I used the CTE in order to create a result set. Just substitute your table for that of the cte
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
December 1, 2009 at 3:17 pm
An alternative would be to use dynamic sql to create your statements and then execute the statement that is necessary.
Another alternative would be to use an if/else statement.
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
December 2, 2009 at 12:26 pm
Thanks All,
i used If/Else to do this...
December 3, 2009 at 12:42 pm
this will work as well
select col1,col2
from Table
where col3 = case when @VarName = 'red' then @VarName else col3 end
and col3 <> case when @VarName = 'red' then '-1' else 'red' end
December 4, 2009 at 12:19 pm
UnionAll (12/2/2009)
Thanks All,i used If/Else to do this...
In this case that is by far the best solution: simple, maintainable, and most important gets you the optimal plan for either condition of input.
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
December 4, 2009 at 1:34 pm
[font="Arial"]I prefer to avoid the IF/ELSE scenario for queries. Eventually, you'll have to "fix it" in two places. Plus, you open up the possibility of two different signatures (selecting different columns in the two queries), which could be problematic.
I'd try to keep it down to one SELECT statement. Here's another option[/font]:
Declare @VarName varchar(40)
select col1,col2
from Table
where (@VarName = 'Red' AND col3 = 'Red')
OR (@VarName <> 'Red' AND col3 <> 'Red')
December 4, 2009 at 1:41 pm
Dave Mason (12/4/2009)
[font="Arial"]I prefer to avoid the IF/ELSE scenario for queries. Eventually, you'll have to "fix it" in two places. Plus, you open up the possibility of two different signatures (selecting different columns in the two queries), which could be problematic.I'd try to keep it down to one SELECT statement. Here's another option[/font]:
Declare @VarName varchar(40)
select col1,col2
from Table
where (@VarName = 'Red' AND col3 = 'Red')
OR (@VarName <> 'Red' AND col3 <> 'Red')
That is actually the hands-down worst thing you can do. GUARANTEED to get you the WRONG plan for one or the other of the inputs, and by wrong I mean horribly inefficient. Never, ever do that type of query.
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
December 4, 2009 at 1:59 pm
Dave Mason (12/4/2009)
[font="Arial"]I prefer to avoid the IF/ELSE scenario for queries. Eventually, you'll have to "fix it" in two places. Plus, you open up the possibility of two different signatures (selecting different columns in the two queries), which could be problematic.
Often multiple queries, or even multiple procedures, are the best option from a performance point of view. Yes, it's more maintenance, but if the if the single select statement takes several times the duration of the separate ones, it's not a good trade-off
See http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/ and, to a lesser extent, http://sqlinthewild.co.za/index.php/2009/09/15/multiple-execution-paths/
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
December 15, 2009 at 8:19 am
i personally think this will perform the best. Simply because it is or-less. Or's hurt. Sure it may be a little hard to wrap your mind around which will hurt maintainability however it is still short and to the point.
select col1,col2
from Table
where col3 = case when @VarName = 'red' then @VarName else col3 end
and col3 <> case when @VarName = 'red' then '-1' else 'red' end
December 15, 2009 at 9:39 am
BaldingLoopMan (12/15/2009)
i personally think this will perform the best. Simply because it is or-less. Or's hurt. Sure it may be a little hard to wrap your mind around which will hurt maintainability however it is still short and to the point.select col1,col2
from Table
where col3 = case when @VarName = 'red' then @VarName else col3 end
and col3 <> case when @VarName = 'red' then '-1' else 'red' end
1) how would that work if @varname contained NULL?
2) Did you actually TRY your query method? Here is a demonstration of it being just as bad as ORs
use AdventureWorks
dbcc freeproccache --careful using this on production system!
declare @SalesPersonID int
SET @SalesPersonID = 288 --16 rows, should do index seek and bookmark lookup for most efficient plan
select *
from Sales.SalesOrderHeader
where SalesPersonID = case when @SalesPersonID = 288 then @SalesPersonID ELSE SalesPersonID END
AND SalesPersonID <> case when @SalesPersonID = 288 then -999999 ELSE 288 END
--this query does a full table scan with 2 scalar computes, with an estimated row count of 2831.85 after the filter, 16 rows output
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply