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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

DateDiff with time excluding weekends

Hi All,

I have a date table and fact table which are connected to each other via one-to-many.

I'm using the following dax to get the out put:

#Days_Den =

VAR _d = DATEDIFF([ExpectedStartDate], [ExpectedEndDate], SECOND)
VAR _min = DIVIDE(_d,60)
VAR _hour = DIVIDE(_min,60)
VAR _day = DIVIDE(_hour,24)
VAR _weekend = CALCULATE([SumWeekEnds],ALL(Dates),FILTER(Dates,Dates[Date]>=SELECTEDVALUE('Table'[StartDate]) && Dates[Date]<=SELECTEDVALUE('Table'[EndDate])))

return
_day - _weekend

the "_weekend" variable is giving output as 1 day which is ruining the whole output and is unable to get the exact difference as needed.

I'm looking for help calculating the difference between two dates along with time which helps me eliminate weekends with the specified timestamp on the record.

Any help on this would be appreciated!

Regards,
Mahesh
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous ,

 

Due to I don't know your data model, I will share a workaround by my sample.

Tables:

vrzhoumsft_0-1698906953794.png

Date = ADDCOLUMNS(CALENDARAUTO(),"Year",YEAR([Date]),"Month",MONTH([Date]),"WeekDay",WEEKDAY([Date],2))

Measure:

#Days_Den = 

VAR _d = DATEDIFF(MAX('Table'[ExpectedStartDate]), MAX('Table'[ExpectedEndDate]), SECOND)
VAR _min = DIVIDE(_d,60)
VAR _hour = DIVIDE(_min,60)
VAR _day = DIVIDE(_hour,24)
VAR _weekend = CALCULATE(COUNT('Date'[Date]),FILTER('Date','Date'[WeekDay] in {6,7} && 'Date'[Date]>=MAX('Table'[ExpectedStartDate]) && 'Date'[Date]<= MAX('Table'[ExpectedEndDate])))

return 
_day - _weekend

Result is as below.

vrzhoumsft_1-1698906992494.png

 

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
Anonymous
Not applicable

Hi @Anonymous ,

 

Due to I don't know your data model, I will share a workaround by my sample.

Tables:

vrzhoumsft_0-1698906953794.png

Date = ADDCOLUMNS(CALENDARAUTO(),"Year",YEAR([Date]),"Month",MONTH([Date]),"WeekDay",WEEKDAY([Date],2))

Measure:

#Days_Den = 

VAR _d = DATEDIFF(MAX('Table'[ExpectedStartDate]), MAX('Table'[ExpectedEndDate]), SECOND)
VAR _min = DIVIDE(_d,60)
VAR _hour = DIVIDE(_min,60)
VAR _day = DIVIDE(_hour,24)
VAR _weekend = CALCULATE(COUNT('Date'[Date]),FILTER('Date','Date'[WeekDay] in {6,7} && 'Date'[Date]>=MAX('Table'[ExpectedStartDate]) && 'Date'[Date]<= MAX('Table'[ExpectedEndDate])))

return 
_day - _weekend

Result is as below.

vrzhoumsft_1-1698906992494.png

 

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.