cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
ktt777
Helper IV
Helper IV

calculate number of days

hi 

how can i write a dax formula to calculate the number of working days ( only count the date, not time) in each month as below.

Number of working days in jan should be 19days ( 15+2+3 =20 but minus 1 as there is overlap in day 15/1/2022).

Number of working days in feb should be 15 days

 

Vehicle From dateTo dateNo of days
A1/1/202215/1/202215 days
A15/1/202216/1/20222 days
A20/1/202222/1/20223 days
A1/2/202210/2/202210 days
A15/2/202216/2/20222 days
A20/2/202222/2/20223 days

 

thanks

1 ACCEPTED SOLUTION
v-luwang-msft
Community Support
Community Support

HI @ktt777 ,

Based on the data you provided, try the following steps.

Step1,create a date table:

Date = CALENDAR("2022,1,1","2022,12,31")

vluwangmsft_0-1657096254552.png

 

 

Step2, calculate date between two date:

day = CALCULATE(COUNTROWS('Date'),FILTER('Date','Date'[Date]>='Table'[From date]&&'Date'[Date]<='Table'[To date]))

Then use the below dax to create new column in order to calculate overlap  day:

rank = RANKX('Table','Table'[From date],,ASC,Dense)
datediff datediff = 
IF (
    'Table'[rank] <> 1,
    IF (
        DATEDIFF (
            'Table'[From date],
            CALCULATE (
                MAX ( 'Table'[To date] ),
                FILTER ( ALL ( 'Table' ), 'Table'[rank] = EARLIER ( 'Table'[rank] ) - 1 )
            ),
            DAY
        ) < 0,
        0,
        DATEDIFF (
            'Table'[From date],
            CALCULATE (
                MAX ( 'Table'[To date] ),
                FILTER ( ALL ( 'Table' ), 'Table'[rank] = EARLIER ( 'Table'[rank] ) - 1 )
            ),
            DAY
        ) + 1
    ),
    0
)

 

Final to get sum  value for every month:

month = MONTH('Table'[From date])

 

sum = CALCULATE(SUM('Table'[day])-SUM('Table'[datediff datediff]),FILTER(ALL('Table'),'Table'[month]=EARLIER('Table'[month])))

Output:

vluwangmsft_1-1657096413815.png

 

You could download my pbix file to learn more details.

 

 

Did I answer your question? Mark my post as a solution!


Best Regards

Lucien

View solution in original post

3 REPLIES 3
v-luwang-msft
Community Support
Community Support

HI @ktt777 ,

Based on the data you provided, try the following steps.

Step1,create a date table:

Date = CALENDAR("2022,1,1","2022,12,31")

vluwangmsft_0-1657096254552.png

 

 

Step2, calculate date between two date:

day = CALCULATE(COUNTROWS('Date'),FILTER('Date','Date'[Date]>='Table'[From date]&&'Date'[Date]<='Table'[To date]))

Then use the below dax to create new column in order to calculate overlap  day:

rank = RANKX('Table','Table'[From date],,ASC,Dense)
datediff datediff = 
IF (
    'Table'[rank] <> 1,
    IF (
        DATEDIFF (
            'Table'[From date],
            CALCULATE (
                MAX ( 'Table'[To date] ),
                FILTER ( ALL ( 'Table' ), 'Table'[rank] = EARLIER ( 'Table'[rank] ) - 1 )
            ),
            DAY
        ) < 0,
        0,
        DATEDIFF (
            'Table'[From date],
            CALCULATE (
                MAX ( 'Table'[To date] ),
                FILTER ( ALL ( 'Table' ), 'Table'[rank] = EARLIER ( 'Table'[rank] ) - 1 )
            ),
            DAY
        ) + 1
    ),
    0
)

 

Final to get sum  value for every month:

month = MONTH('Table'[From date])

 

sum = CALCULATE(SUM('Table'[day])-SUM('Table'[datediff datediff]),FILTER(ALL('Table'),'Table'[month]=EARLIER('Table'[month])))

Output:

vluwangmsft_1-1657096413815.png

 

You could download my pbix file to learn more details.

 

 

Did I answer your question? Mark my post as a solution!


Best Regards

Lucien

tamerj1
Super User
Super User

Hi @ktt777 

Sample file https://we.tl/t-IuoukK27zQ
Here is a measure to calculate monthly working days. However, removing the overlapping days shall be a bet complex as there is no consistant criteria. If this is a msut do then I need to write more DAX.  

1.png2.png3.png

Number of Days = 
SUMX ( 
    VALUES ( 'Date'[Date].[Month] ),
    CALCULATE (
        SUMX (
            CROSSJOIN ( Data, VALUES ('Date'[Date] ) ),
            VAR CurrentDate = 'Date'[Date]
            VAR FromDate = Data[From date]
            VAR ToDate = Data[To date]
            RETURN
                IF ( CurrentDate >= FromDate && CurrentDate <= ToDate, 1 )
        )
    )
)

 

amitchandak
Super User
Super User

@ktt777 , Create a new column like

 

COUNTROWS(FILTER(ADDCOLUMNS(CALENDAR(Table[from Date],Table[to Date]),"WorkDay", if(WEEKDAY([Date],2) <6,1,0)),[WorkDay] =1))

 

How to calculate Business Days/ Workdays, with or without date table: https://youtu.be/Qv4wT8_P-AA



Power BI Features || Datamarts: https://youtu.be/8tskWsJTEpg || Field Parameters : https://youtu.be/lqF3Wa1FllE?t=70
Time Intelligence Decoded : https://youtu.be/aU2aKbnHuWs&t=145s
Did I answer your question? Mark my post as a solution! Appreciate your Kudos !! Proud to be a Super User! !!
Dashboard of My Blogs !! Connect on Linkedin !! Subscribe to my youtube Channel !!
Want To Learn Power BI | Beginners !! Advance Concepts !! Power BI For Tableau User !!

Helpful resources

Announcements
August 2022 update 768x460.jpg

Check it Out!

Click here to learn more about the August 2022 updates!

August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors