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.
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":
Date | Employee | Sick | Running sick days per employee | Long time absence |
02/02/2023 | Employee A | 0 | 0 | 0 |
03/02/2023 | Employee A | 0 | 0 | 0 |
06/02/2023 | Employee A | 0 | 0 | 0 |
07/02/2023 | Employee A | 0 | 0 | 0 |
08/02/2023 | Employee A | 0 | 0 | 0 |
09/02/2023 | Employee A | 0 | 0 | 0 |
10/02/2023 | Employee A | 0 | 0 | 0 |
13/02/2023 | Employee A | 0 | 0 | 0 |
14/02/2023 | Employee A | 0 | 0 | 0 |
15/02/2023 | Employee A | 0 | 0 | 0 |
16/02/2023 | Employee A | 0 | 0 | 0 |
20/02/2023 | Employee A | 0 | 0 | 0 |
21/02/2023 | Employee A | 0 | 0 | 0 |
22/02/2023 | Employee A | 0 | 0 | 0 |
23/02/2023 | Employee A | 0 | 0 | 0 |
24/02/2023 | Employee A | 0 | 0 | 0 |
27/02/2023 | Employee A | 0 | 0 | 0 |
28/02/2023 | Employee A | 0 | 0 | 0 |
01/03/2023 | Employee A | 0 | 0 | 0 |
02/03/2023 | Employee A | 0 | 0 | 0 |
03/03/2023 | Employee A | 0 | 0 | 0 |
06/03/2023 | Employee A | 1 | 1 | 0 |
07/03/2023 | Employee A | 1 | 2 | 0 |
08/03/2023 | Employee A | 1 | 3 | 0 |
09/03/2023 | Employee A | 1 | 4 | 0 |
10/03/2023 | Employee A | 1 | 5 | 0 |
13/03/2023 | Employee A | 1 | 6 | 0 |
14/03/2023 | Employee A | 1 | 7 | 0 |
15/03/2023 | Employee A | 1 | 8 | 0 |
16/03/2023 | Employee A | 1 | 9 | 0 |
17/03/2023 | Employee A | 1 | 10 | 0 |
20/03/2023 | Employee A | 1 | 11 | 0 |
21/03/2023 | Employee A | 0 | 0 | 0 |
22/03/2023 | Employee A | 0 | 0 | 0 |
23/03/2023 | Employee A | 0 | 0 | 0 |
27/03/2023 | Employee A | 0 | 0 | 0 |
28/03/2023 | Employee A | 0 | 0 | 0 |
29/03/2023 | Employee A | 0 | 0 | 0 |
03/04/2023 | Employee A | 1 | 1 | 0 |
04/04/2023 | Employee A | 1 | 2 | 0 |
05/04/2023 | Employee A | 1 | 3 | 0 |
06/04/2023 | Employee A | 1 | 4 | 0 |
11/04/2023 | Employee A | 1 | 5 | 0 |
12/04/2023 | Employee A | 1 | 6 | 0 |
13/04/2023 | Employee A | 1 | 7 | 0 |
14/04/2023 | Employee A | 1 | 8 | 0 |
17/04/2023 | Employee A | 1 | 9 | 0 |
18/04/2023 | Employee A | 1 | 10 | 0 |
19/04/2023 | Employee A | 1 | 11 | 0 |
20/04/2023 | Employee A | 1 | 12 | 0 |
21/04/2023 | Employee A | 1 | 13 | 0 |
24/04/2023 | Employee A | 1 | 14 | 0 |
25/04/2023 | Employee A | 1 | 15 | 0 |
26/04/2023 | Employee A | 1 | 16 | 0 |
27/04/2023 | Employee A | 1 | 17 | 0 |
28/04/2023 | Employee A | 1 | 18 | 0 |
01/05/2023 | Employee A | 0 | 0 | 0 |
02/05/2023 | Employee A | 1 | 1 | 1 |
03/05/2023 | Employee A | 1 | 2 | 1 |
04/05/2023 | Employee A | 1 | 3 | 1 |
05/05/2023 | Employee A | 1 | 4 | 1 |
08/05/2023 | Employee A | 1 | 5 | 1 |
09/05/2023 | Employee A | 1 | 6 | 1 |
10/05/2023 | Employee A | 1 | 7 | 1 |
11/05/2023 | Employee A | 1 | 8 | 1 |
12/05/2023 | Employee A | 1 | 9 | 1 |
15/05/2023 | Employee A | 1 | 10 | 1 |
16/05/2023 | Employee A | 1 | 11 | 1 |
17/05/2023 | Employee A | 1 | 12 | 1 |
19/05/2023 | Employee A | 1 | 13 | 1 |
22/05/2023 | Employee A | 1 | 14 | 1 |
23/05/2023 | Employee A | 1 | 15 | 1 |
24/05/2023 | Employee A | 1 | 16 | 1 |
25/05/2023 | Employee A | 1 | 17 | 1 |
26/05/2023 | Employee A | 1 | 18 | 1 |
30/05/2023 | Employee A | 1 | 19 | 1 |
31/05/2023 | Employee A | 1 | 20 | 1 |
01/06/2023 | Employee A | 1 | 21 | 1 |
02/06/2023 | Employee A | 1 | 22 | 1 |
05/06/2023 | Employee A | 1 | 23 | 1 |
06/06/2023 | Employee A | 1 | 24 | 1 |
07/06/2023 | Employee A | 1 | 25 | 1 |
08/06/2023 | Employee A | 1 | 26 | 1 |
09/06/2023 | Employee A | 1 | 27 | 1 |
12/06/2023 | Employee A | 1 | 28 | 1 |
13/06/2023 | Employee A | 1 | 29 | 1 |
14/06/2023 | Employee A | 1 | 30 | 1 |
15/06/2023 | Employee A | 1 | 31 | 1 |
16/06/2023 | Employee A | 1 | 32 | 1 |
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?
Solved! Go to Solution.
Hi,
Please check the below picture and the attached pbix file.
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.
Schedule a short Teams meeting to discuss your question
Hi,
Please check the below picture and the attached pbix file.
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.
Schedule a short Teams meeting to discuss your question
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
User | Count |
---|---|
18 | |
18 | |
14 | |
14 | |
13 |
User | Count |
---|---|
17 | |
14 | |
11 | |
10 | |
8 |