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

  • 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.

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

    DECLARE @monthINT = 10;

    DECLARE @yearINT = 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.

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • Thanks a ton Koen.

    it worked. 🙂

  • 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. 😀

    --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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • 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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply