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
Anonymous
Not applicable

EOMONTH working days calculation

I have a measure to subtract the total number of days in a month e.g. 31 - absence.

 

Measure =
VAR _lastday =
DAY (
EOMONTH (
DATE ( LEFT ( MAX ( 'DimDate'[Month Year] ), 4 ), VALUE ( RIGHT ( MAX ( 'DimDate'[Month Year] ), 2 ) ), 1 ),
0
)
)
RETURN
IF ( ISBLANK ( [AbsentByDay] ), BLANK (), _lastday ) - [AbsentByDay]
 
Is there a way to only include working days in this calculation e.g. 22 working days in month - absence?
 
e.g. NOT WEEKDAY( 'DimDate'[Date] ) IN { 1,7 }
 
File attached:
1 ACCEPTED SOLUTION

@Anonymous 

The DimDate table has a column, Working Day, I used that as that is your basis for other measures:

Please check now:

 

Measure 3 = 

VAR _Month = 
    EOMONTH (
        DATE ( LEFT ( MAX ( 'DimDate'[Month Year] ), 4 ), VALUE ( RIGHT ( MAX ( 'DimDate'[Month Year] ), 2 ) ), 1 ),
        0
    )
VAR _lastday= 
COUNTROWS(
    FILTER(
        DimDate,
        DimDate[Date] >= EDATE(_Month , -1)+1 && DimDate[Date] <= _Month && DimDate[WorkingDays] = TRUE())
)    

RETURN

 IF ( ISBLANK ( [AbsentByDay] ), BLANK (), _lastday ) - [AbsentByDay]

 

 

________________________

If my answer was helpful, please consider Accept it as the solution to help the other members find it

Click on the Thumbs-Up icon if you like this reply 🙂

YouTube  LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

View solution in original post

4 REPLIES 4
Fowmy
Super User
Super User

@Anonymous 

I have modified the formula to include only workdays, I consider weekday 1 and 7 as weekend, you can change if you need.

Measure = 

VAR _Month = 
    EOMONTH (
        DATE ( LEFT ( MAX ( 'DimDate'[Month Year] ), 4 ), VALUE ( RIGHT ( MAX ( 'DimDate'[Month Year] ), 2 ) ), 1 ),
        0
    )

VAR _lastday= 
COUNTROWS(
    FILTER(
        CALENDAR( EDATE(_Month , -1)+1 , _Month ),
        NOT( WEEKDAY( [Date] ) IN { 1,7 })
    )
)

RETURN
 IF ( ISBLANK ( [AbsentByDay] ), BLANK (), _lastday ) - [AbsentByDay]

 

________________________

If my answer was helpful, please consider Accept it as the solution to help the other members find it

Click on the Thumbs-Up icon if you like this reply 🙂

YouTube  LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

This works great but I'm having trouble with 1 or 2 values not adding up

Working date - absence.PNG

I think person_id 135 was absent twice in month : 201902, is there any way to account for this?

 

https://www.dropbox.com/s/jrvtgfms7akm1fv/Sample2%28updated%29.pbix?dl=0

Anonymous
Not applicable

Working date - absence2.PNG

Looking into this I think the :

VAR _Month =
EOMONTH (
DATE ( LEFT ( MAX ( 'DimDate'[Month Year] ), 4 ), VALUE ( RIGHT ( MAX ( 'DimDate'[Month Year] ), 2 ) ), 1 ),
0
)
 
assumes that there are 30/31 days in each month?

@Anonymous 

The DimDate table has a column, Working Day, I used that as that is your basis for other measures:

Please check now:

 

Measure 3 = 

VAR _Month = 
    EOMONTH (
        DATE ( LEFT ( MAX ( 'DimDate'[Month Year] ), 4 ), VALUE ( RIGHT ( MAX ( 'DimDate'[Month Year] ), 2 ) ), 1 ),
        0
    )
VAR _lastday= 
COUNTROWS(
    FILTER(
        DimDate,
        DimDate[Date] >= EDATE(_Month , -1)+1 && DimDate[Date] <= _Month && DimDate[WorkingDays] = TRUE())
)    

RETURN

 IF ( ISBLANK ( [AbsentByDay] ), BLANK (), _lastday ) - [AbsentByDay]

 

 

________________________

If my answer was helpful, please consider Accept it as the solution to help the other members find it

Click on the Thumbs-Up icon if you like this reply 🙂

YouTube  LinkedIn

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

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.