Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
I have a table holding data regarding absence. To simplify the table holds these columns:
employee no (integer)
absence code (integer)
starting date (date)
ending date (date)
The data going into this table is not necessarily for the whole period, but could be subsets, i.e. May 1 - May 5 and then again May 8 - May 12 (typically excluding weekend days).
Would like to know if any entry is part of a streak that is >= 30 days to identify short term or long term absence. This based on combination of employee and absence code.
Ultimately I need to be able to slice, so I can filter and make measures based on short/term to calculate how much in percent points the short term and long term make up.
As I see it there could be 2 approaches:
1) In PowerQuery try and group the start and end dates. Thinking I could offset Friday to Sunday to include the weekend days. Not sure how to join the periods though.
2) Or this could be done in DAX? Could this be accomplished through a calculated column?
Any advice on how to achieve this? Thanks in advance.
Hi @Anonymous
For a DAX calculated column please try
Absence Type =
VAR T =
CALCULATETABLE (
'Table',
ALLEXCEPT ( 'Table', 'Table'[Employee No], 'Table'[Absence Code] )
)
VAR StartDate =
MINX ( T, 'Table'[Starting Date] )
VAR EndDate1 =
MAXX ( T, 'Table'[Ending Date] )
VAR EndDate2 =
SWITCH ( WEEKDAY ( EndDate1, 2 ), 5, EndDate1 + 2, 6, EndDate1 + 1, EndDate1 )
VAR AbsenceDuration =
DATEDIFF ( StartDate, EndDate2, DAY )
RETURN
IF ( AbsenceDuration >= 30, "Long Term", "Short Term" )
User | Count |
---|---|
21 | |
14 | |
11 | |
8 | |
5 |
User | Count |
---|---|
24 | |
22 | |
20 | |
15 | |
10 |