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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
fitzi44
Regular Visitor

Calculate "Running sick days per employee (long time absences)"

Hi all

I'm currently facing the challenge to create a measure for all our employees which are categorized as "long time absences". The definition for a "long time absence" is, that an employee is "sick" for at least 30 working days running. If he is 30 and more days sick in a row, the period (each date in this period) is automatically defined and flagged as "long time absence":

 

DateEmployeeSickRunning sick days per employeeLong time absence
02/02/2023Employee A000
03/02/2023Employee A000
06/02/2023Employee A000
07/02/2023Employee A000
08/02/2023Employee A000
09/02/2023Employee A000
10/02/2023Employee A000
13/02/2023Employee A000
14/02/2023Employee A000
15/02/2023Employee A000
16/02/2023Employee A000
20/02/2023Employee A000
21/02/2023Employee A000
22/02/2023Employee A000
23/02/2023Employee A000
24/02/2023Employee A000
27/02/2023Employee A000
28/02/2023Employee A000
01/03/2023Employee A000
02/03/2023Employee A000
03/03/2023Employee A000
06/03/2023Employee A110
07/03/2023Employee A120
08/03/2023Employee A130
09/03/2023Employee A140
10/03/2023Employee A150
13/03/2023Employee A160
14/03/2023Employee A170
15/03/2023Employee A180
16/03/2023Employee A190
17/03/2023Employee A1100
20/03/2023Employee A1110
21/03/2023Employee A000
22/03/2023Employee A000
23/03/2023Employee A000
27/03/2023Employee A000
28/03/2023Employee A000
29/03/2023Employee A000
03/04/2023Employee A110
04/04/2023Employee A120
05/04/2023Employee A130
06/04/2023Employee A140
11/04/2023Employee A150
12/04/2023Employee A160
13/04/2023Employee A170
14/04/2023Employee A180
17/04/2023Employee A190
18/04/2023Employee A1100
19/04/2023Employee A1110
20/04/2023Employee A1120
21/04/2023Employee A1130
24/04/2023Employee A1140
25/04/2023Employee A1150
26/04/2023Employee A1160
27/04/2023Employee A1170
28/04/2023Employee A1180
01/05/2023Employee A000
02/05/2023Employee A111
03/05/2023Employee A121
04/05/2023Employee A131
05/05/2023Employee A141
08/05/2023Employee A151
09/05/2023Employee A161
10/05/2023Employee A171
11/05/2023Employee A181
12/05/2023Employee A191
15/05/2023Employee A1101
16/05/2023Employee A1111
17/05/2023Employee A1121
19/05/2023Employee A1131
22/05/2023Employee A1141
23/05/2023Employee A1151
24/05/2023Employee A1161
25/05/2023Employee A1171
26/05/2023Employee A1181
30/05/2023Employee A1191
31/05/2023Employee A1201
01/06/2023Employee A1211
02/06/2023Employee A1221
05/06/2023Employee A1231
06/06/2023Employee A1241
07/06/2023Employee A1251
08/06/2023Employee A1261
09/06/2023Employee A1271
12/06/2023Employee A1281
13/06/2023Employee A1291
14/06/2023Employee A1301
15/06/2023Employee A1311
16/06/2023Employee A1321

 

I'm currently struggling with the task to calulcate the "Running sick days per employee" and therefore also with the calculation of the "Long time absence" flag in DAX.
Does anyone has some help for me?

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_1-1700109033283.png

 

Jihwan_Kim_0-1700109014817.png

Running sick: = 
VAR _list =
    ALL ( Data[Date] )
VAR _t =
    ADDCOLUMNS (
        FILTER ( ALL ( 'Calendar' ), 'Calendar'[Date] IN _list ),
        "@sicktotal", [Sick total:]
    )
VAR _prevsick =
    ADDCOLUMNS (
        _t,
        "@prevsick", MAXX ( OFFSET ( -1, _t, ORDERBY ( 'Calendar'[Date], ASC ) ), [@sicktotal] )
    )
VAR _condition =
    ADDCOLUMNS (
        _prevsick,
        "@condition",
            IF ( [@sicktotal] <> [@prevsick] || [@prevsick] == BLANK (), 1, 0 )
    )
VAR _group =
    ADDCOLUMNS (
        _condition,
        "@group",
            SUMX (
                FILTER ( _condition, 'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] ) ),
                [@condition]
            )
    )
VAR _runningsick =
    ADDCOLUMNS (
        _group,
        "@runningsick",
            SUMX (
                FILTER (
                    _group,
                    'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] )
                        && [@group] = EARLIER ( [@group] )
                ),
                [@sicktotal]
            )
    )
VAR _longtimeabsence =
    ADDCOLUMNS (
        _runningsick,
        "@longtimeabsence",
            IF (
                30
                    IN SUMMARIZE (
                        FILTER ( _runningsick, [@group] = EARLIER ( [@group] ) ),
                        [@runningsick]
                    ),
                1,
                0
            )
    )
RETURN
    MAXX (
        FILTER ( _longtimeabsence, 'Calendar'[Date] = MAX ( 'Calendar'[Date] ) ),
        [@runningsick]
    )

 

Long absence: = 
VAR _list =
    ALL ( Data[Date] )
VAR _t =
    ADDCOLUMNS (
        FILTER ( ALL ( 'Calendar' ), 'Calendar'[Date] IN _list ),
        "@sicktotal", [Sick total:]
    )
VAR _prevsick =
    ADDCOLUMNS (
        _t,
        "@prevsick", MAXX ( OFFSET ( -1, _t, ORDERBY ( 'Calendar'[Date], ASC ) ), [@sicktotal] )
    )
VAR _condition =
    ADDCOLUMNS (
        _prevsick,
        "@condition",
            IF ( [@sicktotal] <> [@prevsick] || [@prevsick] == BLANK (), 1, 0 )
    )
VAR _group =
    ADDCOLUMNS (
        _condition,
        "@group",
            SUMX (
                FILTER ( _condition, 'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] ) ),
                [@condition]
            )
    )
VAR _runningsick =
    ADDCOLUMNS (
        _group,
        "@runningsick",
            SUMX (
                FILTER (
                    _group,
                    'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] )
                        && [@group] = EARLIER ( [@group] )
                ),
                [@sicktotal]
            )
    )
VAR _longtimeabsence =
    ADDCOLUMNS (
        _runningsick,
        "@longtimeabsence",
            IF (
                30
                    IN SUMMARIZE (
                        FILTER ( _runningsick, [@group] = EARLIER ( [@group] ) ),
                        [@runningsick]
                    ),
                1,
                0
            )
    )
RETURN
    MAXX (
        FILTER ( _longtimeabsence, 'Calendar'[Date] = MAX ( 'Calendar'[Date] ) ),
        [@longtimeabsence]
    )

 

 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

View solution in original post

2 REPLIES 2
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_1-1700109033283.png

 

Jihwan_Kim_0-1700109014817.png

Running sick: = 
VAR _list =
    ALL ( Data[Date] )
VAR _t =
    ADDCOLUMNS (
        FILTER ( ALL ( 'Calendar' ), 'Calendar'[Date] IN _list ),
        "@sicktotal", [Sick total:]
    )
VAR _prevsick =
    ADDCOLUMNS (
        _t,
        "@prevsick", MAXX ( OFFSET ( -1, _t, ORDERBY ( 'Calendar'[Date], ASC ) ), [@sicktotal] )
    )
VAR _condition =
    ADDCOLUMNS (
        _prevsick,
        "@condition",
            IF ( [@sicktotal] <> [@prevsick] || [@prevsick] == BLANK (), 1, 0 )
    )
VAR _group =
    ADDCOLUMNS (
        _condition,
        "@group",
            SUMX (
                FILTER ( _condition, 'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] ) ),
                [@condition]
            )
    )
VAR _runningsick =
    ADDCOLUMNS (
        _group,
        "@runningsick",
            SUMX (
                FILTER (
                    _group,
                    'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] )
                        && [@group] = EARLIER ( [@group] )
                ),
                [@sicktotal]
            )
    )
VAR _longtimeabsence =
    ADDCOLUMNS (
        _runningsick,
        "@longtimeabsence",
            IF (
                30
                    IN SUMMARIZE (
                        FILTER ( _runningsick, [@group] = EARLIER ( [@group] ) ),
                        [@runningsick]
                    ),
                1,
                0
            )
    )
RETURN
    MAXX (
        FILTER ( _longtimeabsence, 'Calendar'[Date] = MAX ( 'Calendar'[Date] ) ),
        [@runningsick]
    )

 

Long absence: = 
VAR _list =
    ALL ( Data[Date] )
VAR _t =
    ADDCOLUMNS (
        FILTER ( ALL ( 'Calendar' ), 'Calendar'[Date] IN _list ),
        "@sicktotal", [Sick total:]
    )
VAR _prevsick =
    ADDCOLUMNS (
        _t,
        "@prevsick", MAXX ( OFFSET ( -1, _t, ORDERBY ( 'Calendar'[Date], ASC ) ), [@sicktotal] )
    )
VAR _condition =
    ADDCOLUMNS (
        _prevsick,
        "@condition",
            IF ( [@sicktotal] <> [@prevsick] || [@prevsick] == BLANK (), 1, 0 )
    )
VAR _group =
    ADDCOLUMNS (
        _condition,
        "@group",
            SUMX (
                FILTER ( _condition, 'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] ) ),
                [@condition]
            )
    )
VAR _runningsick =
    ADDCOLUMNS (
        _group,
        "@runningsick",
            SUMX (
                FILTER (
                    _group,
                    'Calendar'[Date] <= EARLIER ( 'Calendar'[Date] )
                        && [@group] = EARLIER ( [@group] )
                ),
                [@sicktotal]
            )
    )
VAR _longtimeabsence =
    ADDCOLUMNS (
        _runningsick,
        "@longtimeabsence",
            IF (
                30
                    IN SUMMARIZE (
                        FILTER ( _runningsick, [@group] = EARLIER ( [@group] ) ),
                        [@runningsick]
                    ),
                1,
                0
            )
    )
RETURN
    MAXX (
        FILTER ( _longtimeabsence, 'Calendar'[Date] = MAX ( 'Calendar'[Date] ) ),
        [@longtimeabsence]
    )

 

 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Visit my LinkedIn page by clicking here.


Schedule a meeting with me to discuss further by clicking here.

Thanks a lot @Jihwan_Kim 

Really great help here. You solution worked, however it was bot very performant in the end in the report, so we opted to implement the logic already on Database level.

 

kind regards and thanks

 

Andreas

Helpful resources

Announcements
September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.