Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.
I have a measure to subtract the total number of days in a month e.g. 31 - absence.
Solved! Go to 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 🙂
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
@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 🙂
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
This works great but I'm having trouble with 1 or 2 values not adding up
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
Looking into this I think the :
@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 🙂
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
16 | |
13 | |
12 | |
11 | |
11 |
User | Count |
---|---|
19 | |
14 | |
14 | |
11 | |
9 |