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


how do i find 5th working day in a month.


how do i find 5th working day in a month.

Author
Message
kishorefeb28
kishorefeb28
Valued Member
Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)

Group: General Forum Members
Points: 53 Visits: 96
Hi Experts,

i would like to know how to find fifth workingday* of a given month and year.
workingday - working day is just any day apart from saturday and sunday. no need to consider any other holidays.

ex: I would just give month number and year as input and i would like to know date and day of the fifth working day.
Input : 10/2013
Output : 7th October 2013, Monday.

any help would be appreciated.

Thank you
Kishore.
Koen Verbeeck
Koen Verbeeck
One Orange Chip
One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)One Orange Chip (27K reputation)

Group: General Forum Members
Points: 27573 Visits: 13268

SET DATEFIRST 1; -- first day of the week is a Monday

DECLARE @month INT = 10;
DECLARE @year INT = 2013;

-- Tally table of 7 rows
WITH CTE_Tally AS
(
SELECT 0 AS Number
UNION ALL
SELECT 1
UNION ALL
SELECT 2
UNION ALL
SELECT 3
UNION ALL
SELECT 4
UNION ALL
SELECT 5
UNION ALL
SELECT 6
)

SELECT resultdate = dates
FROM
(
SELECT dates, RID = ROW_NUMBER() OVER (ORDER BY dates)
FROM
(
SELECT dates = DATEADD(dd,Number,DATEFROMPARTS(@year,@month,1))
FROM CTE_Tally
) tmp
WHERE DATEPART(weekday,dates) NOT IN (6,7) -- filter out saturday and sunday
) tmp2
WHERE RID = 5;



I used the function DATEFROMPARTS, which is only available from SQL Server 2012. Since you posted this question in a SQL 2014 forum, I assume that won't be a problem.


How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?
My blog at SQLKover.

MCSE Business Intelligence - Microsoft Data Platform MVP
kishorefeb28
kishorefeb28
Valued Member
Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)Valued Member (53 reputation)

Group: General Forum Members
Points: 53 Visits: 96
Thanks a ton Koen.
it worked. :-)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87018 Visits: 41112
As much as I love Tally Tables and as high performing as they can be, I find that pure math will frequently beat it (although I've not tested it in this case). This includes a "short circuit" for Tuesday thru Saturday (since we're not considering holidays, the 5th workday is ALWAYS the 7th of the month if the month starts on any of those days). The FROM clause in the following is the good ol' fashioned, backwards compatible way of converting separate INTs for Month and Year to a DATETIME for the first of that month. The number 22801 is 1900*12 months + 1 to get rid of the current month.

I've also made it so the code is not dependent on the value of DATEFIRST so that this can easily be incorporated into a high performance iSF (Inline Scalar Function which is really an Inline Table Valued Function that returns a single value).


DECLARE @pMonth INT
,@pYear INT
;
SELECT @pMonth = 11
,@pYear = 2013
;
SELECT FifthWeekDay =
DATEADD(dd,
CASE
WHEN DATEDIFF(dd,-1,ca.FirstOfMonth)%7 > 1 -- -1 is a Sunday
THEN 7
ELSE 6-DATEDIFF(dd,-1,ca.FirstOfMonth)%7 -- -1 is a Sunday
END
,ca.FirstOfMonth-1)
FROM (SELECT DATEADD(mm,@pYear*12-22801+@pMonth,0))ca(FirstOfMonth)
;



Someone with more caffeine in their system might be able to simplify this even more. :-D

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87018 Visits: 41112
If you only need compatibility back to 2005, then I guess you could call the following a "simplification".

DECLARE  @pMonth INT 
,@pYear INT
,@Date DATETIME
;
SELECT @pMonth = 11
,@pYear = 2013
;
SELECT FifthWeekDay = DATEADD(dd, CASE WHEN d.DoW > 1 THEN 7 ELSE 6-d.DoW END, f.FirstOfMonth-1)
FROM (SELECT DATEADD(mm,@pYear*12-22801+@pMonth,0)) f (FirstOfMonth)
CROSS APPLY (SELECT DATEDIFF(dd,-1,f.FirstOfMonth)%7) d (DoW)
;



--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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