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


Dynamic WHERE statement if stored procedure parameter is null


Dynamic WHERE statement if stored procedure parameter is null

Author
Message
phoenix_
phoenix_
SSC Rookie
SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)

Group: General Forum Members
Points: 32 Visits: 31
I have the stored procedure with @StartDate and @EndDate parameters
my WHERE statement is using those parameters to filter out data

WHERE condition1 and SomeDate >= @StartDate and SomeDate <= @EndDate and condition2

However when @StartDate or @EndDate is null or empty string then WHERE statement should look like below
WHERE condition 1 and condition2

I was trying already to do it with CASE of IF statement but without success so far.
laurie-789651
laurie-789651
SSChasing Mays
SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)SSChasing Mays (616 reputation)

Group: General Forum Members
Points: 616 Visits: 1272
Have you tried dynamic SQL?

Something like this:



declare @sql nvarchar(max),
@Startdate nvarchar(10),
@Enddate nvarchar(10);

set @sql = 'select * from #table1';
set @Startdate = '01/01/1900';
set @Enddate = '01/01/1900';

if @Startdate is not null and @Startdate <> ''
and @Enddate is not null and @Enddate <> ''
set @sql = @sql + ' where Startdate >= ''' + @Startdate + ''' and Enddate <= ''' +@Enddate + ''''

print @sql

exec sp_executesql @sql



phoenix_
phoenix_
SSC Rookie
SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)

Group: General Forum Members
Points: 32 Visits: 31
To be honest with you I don't like dynamic sql because of quotation marks '' which are making whole code harder to read Smile
So Instead of this I developed something like this:
where condition1 and (SomeDate >= CASE WHEN @StartDate is null THEN SomeDate ELSE @StartDate END or SomeDate is null)
and (SomeDate <= CASE WHEN @EndDate is null THEN SomeDate ELSE @EndDate END or SomeDate is null) and condition2

Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26113 Visits: 17538
Oh be careful here Laurie. You suggested using dynamic sql which is a good choice here. However you committed a cardinal sin. You allowed for the parameters to be executed. This is now a sql injection vulnerability. You should instead use parameters to your dynamic sql.

Here is a full working example.


create table #table1
(
StartDate datetime,
EndDate datetime
)

insert #table1
select '1/15/1900', '2/1/1900'

declare @sql nvarchar(max),
@Startdate nvarchar(10),
@Enddate nvarchar(10);

set @sql = 'select * from #table1';
set @Startdate = '01/01/1900';
set @Enddate = '01/01/1901';

if @Startdate > '' AND @Enddate > ''
set @sql = @sql + ' where Startdate >= @Startdate and Enddate <= @Enddate'

print @sql

exec sp_executesql @sql, N'@Startdate datetime, @EndDate datetime', @Startdate = @Startdate, @Enddate = @Enddate

drop table #table1



_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26113 Visits: 17538
phoenix_ (7/10/2013)
To be honest with you I don't like dynamic sql because of quotation marks '' which are making whole code harder to read Smile
So Instead of this I developed something like this:
where condition1 and (SomeDate >= CASE WHEN @StartDate is null THEN SomeDate ELSE @StartDate END or SomeDate is null)
and (SomeDate <= CASE WHEN @EndDate is null THEN SomeDate ELSE @EndDate END or SomeDate is null) and condition2




This will work to a point. You will end up with some serious performance issues with this type of query though. Check out this article from Gail on the topic.

http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Steven Willis
Steven Willis
SSC Eights!
SSC Eights! (827 reputation)SSC Eights! (827 reputation)SSC Eights! (827 reputation)SSC Eights! (827 reputation)SSC Eights! (827 reputation)SSC Eights! (827 reputation)SSC Eights! (827 reputation)SSC Eights! (827 reputation)

Group: General Forum Members
Points: 827 Visits: 1721
I use this syntax in my where clauses rather than case statements:



WHERE
((@StartDate IS NOT NULL AND StartDate >= @StartDate)
OR
(@StartDate IS NULL))
AND ((@EndDate IS NOT NULL AND EndDate <= @EndDate)
OR
(@EndDate IS NULL))



Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26113 Visits: 17538
Steven Willis (7/10/2013)
I use this syntax in my where clauses rather than case statements:



WHERE
((@StartDate IS NOT NULL AND StartDate >= @StartDate)
OR
(@StartDate IS NULL))
AND ((@EndDate IS NOT NULL AND EndDate <= @EndDate)
OR
(@EndDate IS NULL))




You too might want to read that article from Gail. This type of approach can lead to really awful performance.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)SSCertifiable (7.3K reputation)

Group: General Forum Members
Points: 7289 Visits: 6431
Sean Lange (7/10/2013)
phoenix_ (7/10/2013)
To be honest with you I don't like dynamic sql because of quotation marks '' which are making whole code harder to read Smile
So Instead of this I developed something like this:
where condition1 and (SomeDate >= CASE WHEN @StartDate is null THEN SomeDate ELSE @StartDate END or SomeDate is null)
and (SomeDate <= CASE WHEN @EndDate is null THEN SomeDate ELSE @EndDate END or SomeDate is null) and condition2




This will work to a point. You will end up with some serious performance issues with this type of query though. Check out this article from Gail on the topic.

http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/


+1 to you Sean for the link to the bible on this topic.

I saw the subject of this thread and visited to make sure someone had already provided it.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
kapil_kk
kapil_kk
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3087 Visits: 2766
Thanks Sean for that link of Gail :-)

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
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