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


How to get the date?


How to get the date?

Author
Message
Charmer
Charmer
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3304 Visits: 1062
Hi Friends,

I want to write a query to generate a report. I have a date column which will be holding all the business dates. No dates of Saturday and Sunday are allowed.
What I am looking for is, I want to get the result of every 5th business day of each month. A month could start with any day. I just want only the 5th business day.

If I am not clear, please let me know .

Any suggestions would be really appreciated. Thanks in advance.

Thanks,
Charmer
Nevyn
Nevyn
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3572 Visits: 3149
Do you care about holidays or just saturday / sunday?

Do you have access to (or are you willing to create and maintain) a calendar table?


If you need to discount holidays, you need a calendar table. It would likely be a good idea if you don't care about holidays

If you don't care about holidays, and don't have or want a calendar table, the logic you need to determine if any date is the 5th business day of the month is like this:

CASE WHEN DATEPART(weekday,[Date]) = 6 AND DATEPART(day,[Date]) IN (5,6) THEN 1
WHEN DATEPART(weekday,[Date]) IN (2,3,4,5) AND DATEPART(day,[Date]) = 7 THEN 1
ELSE 0 END



Where [Date] is your date field, giving you a 1 when that date is the 5th business day of the month, and a 0 otherwise.

If you want to use this in a query though, you might want to give us some sample ddl, data, and expected output, because throwing the above into a where clause might perform terribly.
hunchback
hunchback
SSChasing Mays
SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)SSChasing Mays (615 reputation)

Group: General Forum Members
Points: 615 Visits: 639
Use a ranking function.

with C1 as (
select *, row_number() over(partition by [year], [month] order by dt) as rnk
from calendar
-- exclude weekends and holidays
-- where isweekend = 0 and isholiday = 0
)
select *
from C1
where rnk = 5;



Charmer
Charmer
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3304 Visits: 1062
Hi Nevyn,

Don't care of holidays. Just caring about Saturday and Sunday.

Thanks,
Charmer
andrew gothard
andrew gothard
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2808 Visits: 5971
I'd still go for a DateDim / Calendar table. Firstly, it means you only have to run your calculations once, and the table is also unaffected by changes to datefirst, for example

I'm a DBA.
I'm not paid to solve problems. I'm paid to prevent them.
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42538 Visits: 19839
Assuming you have @@DATEFIRST = 7, you could use this formula:


SELECT CASE WHEN DATEPART(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()), 0)) = 2
THEN DATEADD( DD, 4, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()), 0))
ELSE DATEADD( DD, 6, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()), 0)) END



Here's a test:

SELECT CASE WHEN DATEPART(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) = 2
THEN DATEADD( DD, 4, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
ELSE DATEADD( DD, 6, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) END
FROM (VALUES(0), (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14))e(n)



It's basically testing if the first day of the month is Monday, then the 5th weekday will be the 5th day of the month, if not, it will be the 7th. You can comment the code to make it obvious or you could use the DATENAME() function instead. ;-)


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Charmer
Charmer
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3304 Visits: 1062
Luis Cazares (3/25/2014)
Assuming you have @@DATEFIRST = 7, you could use this formula:


SELECT CASE WHEN DATEPART(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()), 0)) = 2
THEN DATEADD( DD, 4, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()), 0))
ELSE DATEADD( DD, 6, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()), 0)) END



Here's a test:

SELECT CASE WHEN DATEPART(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) = 2
THEN DATEADD( DD, 4, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
ELSE DATEADD( DD, 6, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) END
FROM (VALUES(0), (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14))e(n)



It's basically testing if the first day of the month is Monday, then the 5th weekday will be the 5th day of the month, if not, it will be the 7th. You can comment the code to make it obvious or you could use the DATENAME() function instead. ;-)


Hi Luis,

It really works. But I am not able to understand the logic of this query. Could you please explain it?

Thanks,
Charmer
Luis Cazares
Luis Cazares
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42538 Visits: 19839
Trying to explain the logic, I found there was a mistake when the first day of a month is Sunday. If you grab a calendar, it becomes evident. From Tuesday to Saturday, you'll end up having a weekend before the fifth day, so you need to look for the 7th day. On Sunday, you only have one day from your weekend and the whole week to get to the fifth business day, so you'll look for the 6th. On Monday, you get no weekends before the 5th business day, so you just use the 5th.

DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) , 0) will give you the first day of the month (the +n in the example is to go through different months). You just need to add the necessary days to get to the 5th, 6th or 7th depending on the day of week of the first.

Here's the updated example:
SELECT CASE DATENAME(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) 
WHEN 'Monday' THEN DATEADD( DD, 4, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
WHEN 'Sunday' THEN DATEADD( DD, 5, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
ELSE DATEADD( DD, 6, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) END
,DATENAME(DW, CASE DATENAME(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
WHEN 'Monday' THEN DATEADD( DD, 4, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
WHEN 'Sunday' THEN DATEADD( DD, 5, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0))
ELSE DATEADD( DD, 6, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) END) AS [5thDay]
,DATENAME(DW, DATEADD( MM, DATEDIFF(MM, 0, GETDATE()) + n, 0)) AS [1stDay]
FROM (VALUES(0), (1),(2),(3),(4),(5),(6),(7),(8),(9),(10),(11),(12),(13),(14))e(n)
ORDER BY [1stDay]




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Charmer
Charmer
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3304 Visits: 1062
Yes Luis...Now I understood. So based on the starting day, we are calculating it. I get it.

Thank you Luis. I appreciate your time.

Thanks,
Charmer
ScottPletcher
ScottPletcher
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19947 Visits: 7415
I prefer to avoid anything that is date or language setting dependent; DATEDIFF(DAY, 0, first_day_of_month) % 7 will yield a value that never changes no matter what the SQL setup is.



SELECT
DATEADD(DAY, CASE DATEDIFF(DAY, 0, first_day_of_month) % 7
WHEN datediff_mod_7_monday THEN 4 WHEN datediff_mod_7_sunday THEN 5 ELSE 6 END, first_day_of_month)
AS [5th_Business_Day_Of_Month]
FROM (
SELECT 00 AS month_increment UNION ALL SELECT 01 UNION ALL SELECT 02 UNION ALL SELECT 03 UNION ALL
SELECT 04 UNION ALL SELECT 05 UNION ALL SELECT 06 UNION ALL SELECT 07 UNION ALL
SELECT 08 UNION ALL SELECT 09 UNION ALL SELECT 10 UNION ALL SELECT 11
) AS month_increments
CROSS APPLY (
SELECT DATEADD(MONTH, DATEDIFF(MONTH, 0, GETDATE()) + month_increment, 0) AS first_day_of_month,
0 AS datediff_mod_7_monday, 6 AS datediff_mod_7_sunday
) AS calculated_data_1




SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
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