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

To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.

Reply
Anonymous
Not applicable

Duration of a task in working days

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?

1 REPLY 1
AlexChen
Microsoft Employee
Microsoft Employee

Hi,

 

I assume you have 2 tables: taskInfo and holidayInfo. See screenshot below.

 

1.png


2.png

 

1.  create relationships between these 2 tables:

 

3.png

 

4.png

 

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:

 

5.png

 

Best Regards

Alex

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

Find out what's new and trending in the Fabric community.

Top Solution Authors
Top Kudoed Authors