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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
Anonymous
Not applicable

Difference between dates considering only working days

I am having a little challenge counting the right number of days between two dates.

If I use DateDiff function it disregards the fact that there are weekend days in the calendar.

If I use Datesbetween function to count the rows in the Date table filtering out weekend days, it works fine only if start date is less then the end date. 

 

I have a situation where start date can be later than the supposedly end date (bad data, i guess).

 

Is there a work around to count the number of days between two dates (positive or negative) AND count only weekdays?

1 ACCEPTED SOLUTION
v-easonf-msft
Community Support
Community Support

Hi, @Anonymous 

You need to created  calculated column Is_WorkDay =1 or 0 to indicate if its a workday  or not in your calendar table. 

Is_workday = IF( NOT WEEKDAY('Calendar'[Date],2)   in {6,7},1,0) 

To avoid the situation where the start date is greater than the end date,you can create a calculated column as below in you fact table (here we set two variables "max1"  and "min1" to get the date in the table)

_Workdays = 
VAR max1 =
    MAX ( 'Table'[StartDate], 'Table'[EndDate] )
VAR min1 =
    MIN ( 'Table'[StartDate], 'Table'[EndDate] )
RETURN
    CALCULATE (
        SUM ( 'Calendar'[Is_workday] ),
        ALL ( 'Calendar' ),
        DATESBETWEEN ( 'Calendar'[Date], min1, max1 )
    )

39.png

 

Best Regards,
Community Support Team _ Eason

View solution in original post

3 REPLIES 3
v-easonf-msft
Community Support
Community Support

Hi, @Anonymous 

You need to created  calculated column Is_WorkDay =1 or 0 to indicate if its a workday  or not in your calendar table. 

Is_workday = IF( NOT WEEKDAY('Calendar'[Date],2)   in {6,7},1,0) 

To avoid the situation where the start date is greater than the end date,you can create a calculated column as below in you fact table (here we set two variables "max1"  and "min1" to get the date in the table)

_Workdays = 
VAR max1 =
    MAX ( 'Table'[StartDate], 'Table'[EndDate] )
VAR min1 =
    MIN ( 'Table'[StartDate], 'Table'[EndDate] )
RETURN
    CALCULATE (
        SUM ( 'Calendar'[Is_workday] ),
        ALL ( 'Calendar' ),
        DATESBETWEEN ( 'Calendar'[Date], min1, max1 )
    )

39.png

 

Best Regards,
Community Support Team _ Eason

amitchandak
Super User
Super User

@Anonymous , Check the second page work day diff

https://www.dropbox.com/s/y47ah38sr157l7t/Order_delivery_date_diff.pbix?dl=0

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube
Anonymous
Not applicable

@Anonymous Please take a look at this- https://www.sqlbi.com/articles/counting-working-days-in-dax/

Hope it helps.

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

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

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.