I have a measure to subtract the total number of days in a month e.g. 31 - absence.
Solved! Go to Solution.
@Niiru1
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
@Niiru1
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 :
@Niiru1
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
Power BI release plans for 2023 release wave 1 describes all new features releasing from April 2023 through September 2023.
Make sure you register today for the Power BI Summit 2023. Don't miss all of the great sessions and speakers!
User | Count |
---|---|
104 | |
58 | |
45 | |
29 | |
24 |
User | Count |
---|---|
133 | |
94 | |
75 | |
44 | |
41 |