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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
TinyElephant
Helper III
Helper III

Calculate number of work days

Hello,

I have gone through some of the posts on this forum. Please have a look at my table.

I want to calculate the number of work days for the series of "Date", i.e. exclude Saturdays, Sundays, and "Holiday" (in Work column). There may not be a holiday in a particular Date Range.

 

 

TinyElephant_0-1628833359443.png

 

EmployeeWorkHoursDate
Person 1Task 1409-Aug-21
Person 1No Work209-Aug-21
Person 1Task 2209-Aug-21
Person 2Task1309-Aug-21
Person 2Task 2109-Aug-21
Person 2Leave409-Aug-21
Person 3No Work309-Aug-21
Person 3Task 2509-Aug-21
Person 1Holiday810-Aug-21
Person 2Holiday810-Aug-21
Person 3Holiday810-Aug-21
Person 1Task 2811-Aug-21
Person 2Task 3811-Aug-21
Person 3Task 4811-Aug-21
Person 1Task 2812-Aug-21
Person 2Task 3812-Aug-21
Person 3Task 2812-Aug-21
1 ACCEPTED SOLUTION

Hi @TinyElephant ,

I created a sample pbix file(see attachment) for you, please check whether that is what you want.

Create the below 2 measures to get the number of work days:

Number of work days = 
CALCULATE (
    DISTINCTCOUNT ( 'Table'[Date] ),
    FILTER (
        'Table',
        'Table'[Work] <> "Holiday"
            && WEEKDAY ( 'Table'[Date], 2 ) < 6
    )
)
Measure = SUMX(VALUES('Table'[Employee]),[Number of work days])

yingyinr_0-1629098940722.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
amitchandak
Super User
Super User

@TinyElephant , between which range you wany workday?

Not very clear with example

The dates are mentioned in the Date column. In the image here you can see the date entries from 09 Aug 2021 to 12 Aug 2021. I don't want to manually mention the start and end date but to automatically pick it up from the Date column.
Later I would like to control the dashboard visuals using a Date Ranger slider.

Hi @TinyElephant ,

I created a sample pbix file(see attachment) for you, please check whether that is what you want.

Create the below 2 measures to get the number of work days:

Number of work days = 
CALCULATE (
    DISTINCTCOUNT ( 'Table'[Date] ),
    FILTER (
        'Table',
        'Table'[Work] <> "Holiday"
            && WEEKDAY ( 'Table'[Date], 2 ) < 6
    )
)
Measure = SUMX(VALUES('Table'[Employee]),[Number of work days])

yingyinr_0-1629098940722.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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