Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more
We have a table with tasks. Each task has a unique ID, a start date and an end date. We would like to calculate the number of days it took from start to finish. We know that we can subtract the dates to get to that number.
However, we would like to calculate the number of actual working days, not just calendar dates. We have a table with every day in the year, including the day of the week and indicating if the day is a holiday.
How can we calculate the actual number of working days?
Hi,
I assume you have 2 tables: taskInfo and holidayInfo. See screenshot below.
1. create relationships between these 2 tables:
2. create a column called “countOfdays “ in “taskInfo” table:
countOfdays = DATEDIFF([start date], [end date], DAY) + 1
3. create a column called “countOfHolidays “ in “taskInfo” table:
countOfHolidays = COUNTAX(Filter(holidayInfo, holidayInfo[date] >= taskInfo[start date] && holidayInfo[date] <= taskInfo[end date] && holidayInfo[isHoliday] = "Y"), holidayInfo[isHoliday])
4. create a column called “workingDays” in “taskInfo” table:
workingDays = [countOfdays] - [countOfHolidays]
Now you will see the result:
Best Regards
Alex
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.