SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Using Case within the Where Clause
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

dutchgold647
Starting Member

9 Posts

Posted - 06/19/2013 :  22:43:37  Show Profile  Reply with Quote
Hi everyone,

I'm trying to get a MS - SQL query to run so that if todays day is Thursday or Friday, it runs for a date scheduled 4 days away. If it's any other day, it's to run for a date scheduled 2 days away.

Below is what I've got at the moment so any help anyone has will be much appreciated.

SELECT [ID]
,[No]
,[DateSched]

FROM [TransSheet]

Where DateSched between
case when DATEPART(DW, GETDATE()) in (5,6) then DATEADD(DD, DATEDIFF(DD,0,GETDATE()+4),0) and DATEADD(DD, DATEDIFF(DD,0,GETDATE()+4),0)
Else DATEADD(DD, DATEDIFF(DD,0,GETDATE()+2),0) and DATEADD(DD, DATEDIFF(DD,0,GETDATE()+2),0)
End

Thanks everyone

waterduck
Aged Yak Warrior

Malaysia
942 Posts

Posted - 06/19/2013 :  23:01:42  Show Profile  Reply with Quote

SELECT
[ID]
,[No]
,[DateSched]
FROM TransSheet
Where (((DATEPART(DW, getdate()) IN (5,6)) and (DateSched = cast(getdate()+4 as date))) or ((DATEPART(DW, getdate()) NOT IN (5,6)) and (DateSched = cast(getdate()+2 as date))))
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52249 Posts

Posted - 06/20/2013 :  00:48:11  Show Profile  Reply with Quote
The below solution is independent of any server settings
All the previous ones rely upon DATEFIRST setting


SELECT [ID]
,[No]
,[DateSched]
FROM [TransSheet]
Where DateSched >=DATEADD(dd,DATEDIFF(dd,0,GETDATE()),CASE WHEN DATEDIFF(dd,0,GETDATE()) % 7 IN (2,3) THEN 4 ELSE 2 END)
AND DateSched < DATEADD(dd,DATEDIFF(dd,0,GETDATE()),CASE WHEN DATEDIFF(dd,0,GETDATE()) % 7 IN (2,3) THEN 5 ELSE 3 END)


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

dutchgold647
Starting Member

9 Posts

Posted - 06/20/2013 :  03:28:45  Show Profile  Reply with Quote
and the winner is waterduck!

thank you to you both for helping me out here.

cheers
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52249 Posts

Posted - 06/20/2013 :  03:33:27  Show Profile  Reply with Quote
quote:
Originally posted by dutchgold647

and the winner is waterduck!

thank you to you both for helping me out here.

cheers


Does that mean my solution didnt work for you?
Both the solutions are equivalent except for the fact that one relies upon DATEFIRST setting of the server whilst mine doesnt and works irrespective of it.

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

dutchgold647
Starting Member

9 Posts

Posted - 06/20/2013 :  03:40:46  Show Profile  Reply with Quote
Hi visakh16,

Your solution worked perfectly

I said the winner was waterduck because he got there first.

Nothing wrong with your solution though.

Cheers,
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52249 Posts

Posted - 06/20/2013 :  03:45:34  Show Profile  Reply with Quote
quote:
Originally posted by dutchgold647

Hi visakh16,

Your solution worked perfectly

I said the winner was waterduck because he got there first.

Nothing wrong with your solution though.

Cheers,


Ok..Fine
I always prefer writing server independent code as its more flexible and can be easily ported to other servers without worrying on regional/server settings

http://visakhm.blogspot.com/2012/08/creating-server-independent-day.html

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

ditch
Flowing Fount of Yak Knowledge

South Africa
1466 Posts

Posted - 06/20/2013 :  03:48:12  Show Profile  Visit ditch's Homepage  Reply with Quote
Visakh raised a valid point that is often overlooked and has the potential to come back and bite you at some point.
A change in the DATEFIRST setting will render incorrect results.

Duane.
http://ditchiecubeblog.wordpress.com/
Go to Top of Page

dutchgold647
Starting Member

9 Posts

Posted - 06/20/2013 :  03:52:17  Show Profile  Reply with Quote
Ah ok cool, thanks visakh16

I'm pretty new to all this so didn't really understand the difference so thanks for pointing it out.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52249 Posts

Posted - 06/20/2013 :  03:56:30  Show Profile  Reply with Quote
No problem
you're welcome
just wanted you to be aware of the raised point

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.08 seconds. Powered By: Snitz Forums 2000