March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
I already have a Dimension Dates table and one of the columns looks like this
Day DayofWeek
Sunday 1
Monday 2
Tuesday 3
Wednesday 4
Thursday 5
Friday 6
Saturday 7
I have a measure that return if a day is a weekday like this:
IsWeekday = IF(OR(DimDates(DayofWeek) = 1, DimDates(DayofWeek) = 7), "Yes", "No")
I am now trying to use DATEDIFF to calculate the time between two columns. 'ScheduledDate' and 'CompletedDate'.
Thanks!
Solved! Go to Solution.
Hi @water-guy-5
You could do something like this basicly counting the rows in the DimDate table with the filters applied.
This function includes both the first and last day. But your business requirement might be different. But that can easily be changed in de variables.
Working days =
VAR startdate = MAX(Table[ScheduledDate])
VAR enddate = MAX(Table[CompletedDate])
RETURN
CALCULATE(
COUNTROWS('DimDate'),
DATESBETWEEN('DimDate'[Date], startdate, enddate),
'DimDate'[DayOfweek] > 1 && 'DimDate'[DayOfweek] < 7)
Best regards
jeroen,
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
Hi @water-guy-5
If you want a calculated column, here is an example. See Counting working days in DAX - SQLBI
Sales[DeliveryWorkingDays] =
CALCULATE(
COUNTROWS ( 'Date'),
DATESBETWEEN ( 'Date'[Date], Sales[Order Date], Sales[Delivery Date] – 1 ),
'Date'[IsWorkingDay] = TRUE,
ALL ( Sales )
)
Take notice that when using DATESBETWEEN(<Dates>, <StartDate>, <EndDate>), if StartDate is larger than EndDate, the result is an empty table. So you may need to add an IF condition to decide which date ('ScheduledDate' and 'CompletedDate') is larger before calculating net working days.
Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.
You may want to double check your IsWeekday measure. It looks to me like you have your YES and No reversed.
If Weekday = 1 or 7, then it is a Weekend, not Weekday. Just wanna make sure you get this part correct.
Regards,
Hi @water-guy-5
You could do something like this basicly counting the rows in the DimDate table with the filters applied.
This function includes both the first and last day. But your business requirement might be different. But that can easily be changed in de variables.
Working days =
VAR startdate = MAX(Table[ScheduledDate])
VAR enddate = MAX(Table[CompletedDate])
RETURN
CALCULATE(
COUNTROWS('DimDate'),
DATESBETWEEN('DimDate'[Date], startdate, enddate),
'DimDate'[DayOfweek] > 1 && 'DimDate'[DayOfweek] < 7)
Best regards
jeroen,
If this post helps, please consider accepting it as the solution to help the other members find it more quickly.
Appreciate your Kudos!!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
114 | |
76 | |
57 | |
52 | |
44 |
User | Count |
---|---|
165 | |
116 | |
63 | |
57 | |
50 |