Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
PaulMac
Helper IV
Helper IV

Count Working Days Excluding Weekend and Holidays

Hello,

I would like help to produce a column that counts the number of working days between the Date Received column and the Date Acknowledged column that excludes dates that fall on weekends and UK holidays.

 

I have tried following some examples for historical Power BI forum posts but all these seem to equate to an error.

 

So, I have produced this sample file with the aim that this will help to provide a workable solution.

 

Many thanks in advance for your assistance.

 

PaulMc

 

Link to Sample File - Let me know if there are issues accessing the file.

1 ACCEPTED SOLUTION
Cmcmahan
Resident Rockstar
Resident Rockstar

Sure. I added this measure as another value in the table you provided:

Working Days = 
COUNTROWS( 
    FILTER(
        ALL(DateDimension), 
        DateDimension[Day of Week] <> 5 && DateDimension[Day of Week] <> 6 && 
        DateDimension[Is Public Holiday?] = "No" && 
        DateDimension[Date] < SELECTEDVALUE(Data[Date Acknowledged]) && 
        DateDimension[Date] >= SELECTEDVALUE(Data[Date Received]) 
    ) 
)

I wasn't sure whether to count the day it was acknowledged or the day it was received in the count, so I just picked one.  For example, if an item was acknowledged and then received on the next day, should that be 1 (since one day has passed) or 2 (there have been 2 calendar days involved)?  If it was acknowledged on Friday and recieved on Sunday, should that be 1(counting Friday) or 0 (since no business days have passed since acknowledgement)?  Change the less than/greater than or equal to signs accordingly.

View solution in original post

4 REPLIES 4
Cmcmahan
Resident Rockstar
Resident Rockstar

Sure. I added this measure as another value in the table you provided:

Working Days = 
COUNTROWS( 
    FILTER(
        ALL(DateDimension), 
        DateDimension[Day of Week] <> 5 && DateDimension[Day of Week] <> 6 && 
        DateDimension[Is Public Holiday?] = "No" && 
        DateDimension[Date] < SELECTEDVALUE(Data[Date Acknowledged]) && 
        DateDimension[Date] >= SELECTEDVALUE(Data[Date Received]) 
    ) 
)

I wasn't sure whether to count the day it was acknowledged or the day it was received in the count, so I just picked one.  For example, if an item was acknowledged and then received on the next day, should that be 1 (since one day has passed) or 2 (there have been 2 calendar days involved)?  If it was acknowledged on Friday and recieved on Sunday, should that be 1(counting Friday) or 0 (since no business days have passed since acknowledgement)?  Change the less than/greater than or equal to signs accordingly.

@CmcmahanYou! Are! A! Star!

 

Now, is there a way I can tweak your DAX measure to do the samething but as a custom column in Power Query?

 

Many thanks

PaulMc

You can create calculated columns with DAX, no need to involve Power Query.  https://docs.microsoft.com/en-us/power-bi/desktop-tutorial-create-calculated-columns

 

All you should need to do is to replace SELECTEDVALUE in the above query with EARLIER, due to the different context.

@PaulMac you can also try following measure

 

Days Count =
VAR __dateTable =
    CALENDAR ( MAX ( Data[Date Received] ), MAX ( Data[Date Acknowledged] ) )
VAR __table =
    INTERSECT (
        __dateTable,
        CALCULATETABLE (
            VALUES ( DateDimension[Date] ),
            ALL ( DateDimension ),
            DateDimension[Is Public Holiday?] = "No",
            DateDimension[Day of Week] <= 4
        )
    )
RETURN
    COUNTROWS ( __table )


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.