Hi,
I'm looking for a DAX to calculate below End Time.
Here is the example:
Unit Start Time End Time
Unit 1 1/1/2022 7:00:00am
Unit 1 1/1/2022 7:05:00am
Unit 2 1/1/2022 7:00:00am
Unit 2 1/1/2022 7:10:00am
If there’s no other event for the same unit, use the last Power BI dataset refresh time stamp as the End.
If the two events for the same unit spans different months, use the midnight time stamp 00:00 on the last day of the month as the End for the 1st event of the two events.
Can anyone help me with the DAX to achieve this?
Solved! Go to Solution.
Hi @jingxiawang ,
Please try this calculated column
End Time =
VAR _next =
MAXX (
FILTER (
'Table',
[Unit] = EARLIER ( 'Table'[Unit] )
&& [Start Time] > EARLIER ( 'Table'[Start Time] )
),
[Start Time]
)
VAR _last =
MAXX (
FILTER (
'Table',
[Unit] = EARLIER ( 'Table'[Unit] )
&& [Start Time] < EARLIER ( 'Table'[Start Time] )
),
[Start Time]
)
RETURN
IF (
ISBLANK ( _next ),
IF (
DATEDIFF ( _last, [Start Time], MONTH ) > 0,
EOMONTH ( [Start Time], 0 ),
NOW ()
),
_next
)
Here's the results:
Best Regards,
Stephen Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks, Amit. It worked perfectly to handle the 1st part of the calculation. But it still does not handle below logic:
Is there anyway we can include these two logic in the DAX?
@jingxiawang , a new column
minx(filter(Table, [Unit] = EARLIER([Unit]) && [Start Time] > earlier([[Start Time]) ),[Start Time])
or
coalesce(minx(filter(Table, [Unit] = EARLIER([Unit]) && [Start Time] > earlier([[Start Time]) ),[Start Time]), [Start Time])
Thanks, Amit. It worked perfectly to handle the 1st part of the calculation. But it still does not handle below logic:
Is there anyway we can include these two logic in the DAX?
Hi @jingxiawang ,
Please try this calculated column
End Time =
VAR _next =
MAXX (
FILTER (
'Table',
[Unit] = EARLIER ( 'Table'[Unit] )
&& [Start Time] > EARLIER ( 'Table'[Start Time] )
),
[Start Time]
)
VAR _last =
MAXX (
FILTER (
'Table',
[Unit] = EARLIER ( 'Table'[Unit] )
&& [Start Time] < EARLIER ( 'Table'[Start Time] )
),
[Start Time]
)
RETURN
IF (
ISBLANK ( _next ),
IF (
DATEDIFF ( _last, [Start Time], MONTH ) > 0,
EOMONTH ( [Start Time], 0 ),
NOW ()
),
_next
)
Here's the results:
Best Regards,
Stephen Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
User | Count |
---|---|
224 | |
81 | |
81 | |
79 | |
51 |
User | Count |
---|---|
174 | |
93 | |
85 | |
80 | |
72 |