Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
In this dataset, I have rows of data that share the same 'PhaseID'. I want to calculate the differance (in days) between the first 'ScheduledStartDate' and the last 'ScheduledCompleteDate' for each row that shares the same 'PhaseID'.
For Example, for PhaseID 89578 the first ScheduledStartDate = 10/22/21 and the last ScheduledCompleteDate = 11/8/2021 so the differance would be 18 days. I also want to exclude weekends in the calculation.
Help is appreciated!
Solved! Go to Solution.
Hi @vincenardo
You can try this measure to get diff between ScheduledStartDate & ScheduledCompleteDate.
diff =
var _min=CALCULATE(MIN('Table'[ScheduledStartDate]),ALLEXCEPT('Table','Table'[PhaseID]))
var _max=CALCULATE(MAX('Table'[ScheduledCompleteDate]),ALLEXCEPT('Table','Table'[PhaseID]))
return
DATEDIFF(_min,_max,DAY)+1
and if you want to exclude weekends in the calculation, then add a calendar table, and use the measure bellow
diff =
var _min=CALCULATE(MIN('Table'[ScheduledStartDate]),ALLEXCEPT('Table','Table'[PhaseID]))
var _max=CALCULATE(MAX('Table'[ScheduledCompleteDate]),ALLEXCEPT('Table','Table'[PhaseID]))
return
CALCULATE(COUNTROWS('Calendar'),DATESBETWEEN('Calendar'[Date],_min,_max),'Calendar'[Isweekday]<>7&&'Calendar'[Isweekday]<>1)
result
Best Regards,
Community Support Team _Tang
If this post helps, please consider Accept it as the solution to help the other members find it more quickly.
Hi @vincenardo
You can try this measure to get diff between ScheduledStartDate & ScheduledCompleteDate.
diff =
var _min=CALCULATE(MIN('Table'[ScheduledStartDate]),ALLEXCEPT('Table','Table'[PhaseID]))
var _max=CALCULATE(MAX('Table'[ScheduledCompleteDate]),ALLEXCEPT('Table','Table'[PhaseID]))
return
DATEDIFF(_min,_max,DAY)+1
and if you want to exclude weekends in the calculation, then add a calendar table, and use the measure bellow
diff =
var _min=CALCULATE(MIN('Table'[ScheduledStartDate]),ALLEXCEPT('Table','Table'[PhaseID]))
var _max=CALCULATE(MAX('Table'[ScheduledCompleteDate]),ALLEXCEPT('Table','Table'[PhaseID]))
return
CALCULATE(COUNTROWS('Calendar'),DATESBETWEEN('Calendar'[Date],_min,_max),'Calendar'[Isweekday]<>7&&'Calendar'[Isweekday]<>1)
result
Best Regards,
Community Support Team _Tang
If this post helps, please consider Accept it as the solution to help the other members find it more quickly.
@vincenardo , You can create a new column like
Work Day = COUNTROWS(FILTER(ADDCOLUMNS(CALENDAR(Table[ShceduleStartDate],Table[ShceduleCompleted Date]),"WorkDay", if(WEEKDAY([Date],2) <6,1,0)),[WorkDay] =1))
Business Days/ Workdays, with or without date table: https://youtu.be/Qv4wT8_P-AA
Thanks. I have an error becuase I also have records with blank dates in the date fields. What conditional statement could I add?
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
88 | |
86 | |
82 | |
65 | |
49 |
User | Count |
---|---|
138 | |
110 | |
104 | |
66 | |
64 |