Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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?
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
63 | |
63 | |
53 | |
39 | |
25 |
User | Count |
---|---|
85 | |
57 | |
45 | |
43 | |
38 |