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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
aktripathi2506
Helper IV
Helper IV

Calculating number of days between two dates

Hi,

 

I have two dates columns and I want to calculate the number of working days between those two dates? like network days in excel.

How can we do this here in power BI?

 

Thanks.

1 ACCEPTED SOLUTION
v-haibl-msft
Microsoft Employee
Microsoft Employee

@aktripathi2506

 

Assume you have a dataset as below. We can create a calendar table and add a column in it to mark the working days. Then create a column in NetWorkDays table to show the number of working days.

Calculating number of days between two dates_1.jpg

 

  1. Create a calendar table and add a column. Create a 1:1 relationship between DimDate(Date) and Holidays(Date).
    DimDate = 
    CALENDAR ( MIN ( NetWorkDays[Start date] ), MAX ( NetWorkDays[End date] ) )
    
    WorkingDay_Mark = 
    VAR WeekDayNum =
        WEEKDAY ( DimDate[Date] )
    RETURN
        (
            IF (
                OR (
                    OR ( WeekDayNum = 1, WeekDayNum = 7 ),
                    RELATED ( Holidays[Date] ) <> BLANK ()
                ),
                FALSE (),
                TRUE ()
            )
    )
    Calculating number of days between two dates_2.jpg
  2. Create a column in NetWorkDays table.
    WorkingDay_Num = 
    COUNTROWS (
        FILTER (
            DimDate,
            AND (
                AND (
                    DimDate[Date] >= NetWorkDays[Start date],
                    DimDate[Date] <= NetWorkDays[End date]
                ),
                DimDate[WorkingDay_Mark]
            )
        )
    )
    Calculating number of days between two dates_3.jpg

View solution in original post

6 REPLIES 6
v-haibl-msft
Microsoft Employee
Microsoft Employee

@aktripathi2506

 

Assume you have a dataset as below. We can create a calendar table and add a column in it to mark the working days. Then create a column in NetWorkDays table to show the number of working days.

Calculating number of days between two dates_1.jpg

 

  1. Create a calendar table and add a column. Create a 1:1 relationship between DimDate(Date) and Holidays(Date).
    DimDate = 
    CALENDAR ( MIN ( NetWorkDays[Start date] ), MAX ( NetWorkDays[End date] ) )
    
    WorkingDay_Mark = 
    VAR WeekDayNum =
        WEEKDAY ( DimDate[Date] )
    RETURN
        (
            IF (
                OR (
                    OR ( WeekDayNum = 1, WeekDayNum = 7 ),
                    RELATED ( Holidays[Date] ) <> BLANK ()
                ),
                FALSE (),
                TRUE ()
            )
    )
    Calculating number of days between two dates_2.jpg
  2. Create a column in NetWorkDays table.
    WorkingDay_Num = 
    COUNTROWS (
        FILTER (
            DimDate,
            AND (
                AND (
                    DimDate[Date] >= NetWorkDays[Start date],
                    DimDate[Date] <= NetWorkDays[End date]
                ),
                DimDate[WorkingDay_Mark]
            )
        )
    )
    Calculating number of days between two dates_3.jpg

@v-haibl-msft 

When creating a new column using the below code, this method equates to an #ERROR (see attached screenshot)

 

WorkingDay_Num = 
COUNTROWS (
    FILTER (
        DimDate,
        AND (
            AND (
                DimDate[Date] >= NetWorkDays[Start date],
                DimDate[Date] <= NetWorkDays[End date]
            ),
            DimDate[WorkingDay_Mark]
        )
    )
)

Why doesn't it like these columns? Just because they are not DAX!!??Why doesn't it like these columns? Just because they are not DAX!!??Frustrating that forum user examples vary from what can actually be done in Power BIFrustrating that forum user examples vary from what can actually be done in Power BI

 

Were your columns on the 'NetworkDays' table named [Start Date] & [End Date] DAX/Measures?

 

Is there any reason why I can only choose measures?

What need to do if we mark like monday is holiday ?

in the ablove code

Do you have a 'Working Day' marker or identifier in your Date Dimension table?
If so, you can use this to mark Monday's as a non-working day and it can then be excluded from future calculations.

MR2001
Helper II
Helper II

Please have alook at this, it may answer your question:

 

http://www.powerpivotpro.com/2012/11/networkdays-equivalent-in-powerpivot/

 

Can you try something like:

 

=CALCULATE(SUM(Dates[IsWorkday]),
           DATESBETWEEN(Dates[Date], 
                        TwoDates[Column1],
                        TwoDates[Column2]                       )
          )

 

mircea
Helper I
Helper I

Please have alook at this, it may answer your question:

 

http://www.powerpivotpro.com/2012/11/networkdays-equivalent-in-powerpivot/

 

Can you try something like:

=CALCULATE(SUM(Dates[IsWorkday]),
           DATESBETWEEN(Dates[Date], 
                        TwoDates[Column1],
                        TwoDates[Column2]                       )
          )

Helpful resources

Announcements
June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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