Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
I have a table containing Dates when Responsibility gets set, see below.
This Responsibility Set Date produces very close to what I'm trying to achieve: I want to capture the CreateDate any time the Responsibility changes:
But in cases where there are multiple records per responsibility, the _current (MIN) variable reverts back to the initial CreateDate. So, I get why it's producing the results it is, but am not sure how to get it to produce the desired results.
For the rows with red x's (Index rows 8 and 10), I need to see:
Index row 8 = 12/14/2022 3:39:28 PM (capturing the CreateDate of row 7 at Responsibility change)
Index row 10 = 12/20/2022 3:53:28 PM (capturing the CreateDate of row 9 at Responsibility change)
Here's the dax currently generating the Responsibility Set Date results. I'm sure this is a simple fix, but it's been vexing for hours. Any help would be appreciated!
Responsibility Set Date =
VAR previous =
CALCULATE(
DISTINCT(LOA_Logs[Responsibility]),
LOA_Logs[Index per LOA] = (EARLIER(LOA_Logs[Index per LOA]) - 1),
ALLEXCEPT(LOA_Logs, LOA_Logs[LOA_UID], LOA_Logs[Responsibility])
)
VAR _current =
CALCULATE(MIN(LOA_Logs[CreateDate]),
FILTER(LOA_Logs,
LOA_Logs[LOA_UID] = EARLIER(LOA_Logs[LOA_UID]) &&
LOA_Logs[Responsibility] = EARLIER(LOA_Logs[Responsibility]))
)
RETURN
IF(LOA_Logs[Responsibility] <> previous, LOA_Logs[CreateDate], _current)
Solved! Go to Solution.
Hi @dkpcr5
First create a calculated column as follows
Index2 =
LOA_Logs[Index per LOA]
- RANKX (
CALCULATETABLE (
LOA_Logs,
ALLEXCEPT ( LOA_Logs, LOA_Logs[LOA_UID], LOA_Logs[Responsibility] )
),
LOA_Logs[Index per LOA],
,
ASC,
DENSE
)
The the following can be either a measure or a calculated column
Responsibility Set Date =
MINX (
CALCULATETABLE (
LOA_Logs,
ALLEXCEPT ( LOA_Logs, LOA_Logs[LOA_UID], LOA_Logs[Index2] )
),
LOA_Logs[CreateDate]
)
Hi @dkpcr5
First create a calculated column as follows
Index2 =
LOA_Logs[Index per LOA]
- RANKX (
CALCULATETABLE (
LOA_Logs,
ALLEXCEPT ( LOA_Logs, LOA_Logs[LOA_UID], LOA_Logs[Responsibility] )
),
LOA_Logs[Index per LOA],
,
ASC,
DENSE
)
The the following can be either a measure or a calculated column
Responsibility Set Date =
MINX (
CALCULATETABLE (
LOA_Logs,
ALLEXCEPT ( LOA_Logs, LOA_Logs[LOA_UID], LOA_Logs[Index2] )
),
LOA_Logs[CreateDate]
)
@dkpcr5 , Use Max in place of Min
Responsibility Set Date =
VAR previous =
CALCULATE(
DISTINCT(LOA_Logs[Responsibility]),
filter(LOA_Logs, LOA_Logs[Index per LOA] = (EARLIER(LOA_Logs[Index per LOA]) - 1) &&
LOA_Logs[LOA_UID] = earlier(LOA_Logs[LOA_UID]) && LOA_Logs[Responsibility] = earlier(LOA_Logs[Responsibility]) )
)
VAR _current =
CALCULATE(MAX(LOA_Logs[CreateDate]),
FILTER(LOA_Logs,
LOA_Logs[LOA_UID] = EARLIER(LOA_Logs[LOA_UID]) &&
LOA_Logs[Responsibility] = EARLIER(LOA_Logs[Responsibility]))
)
RETURN
IF(LOA_Logs[Responsibility] <> previous, LOA_Logs[CreateDate], _current)
Thanks for the assist @amitchandak, though unfortunately, this doesn't work. When I change MIN to MAX, I get a changing "Responsibility Set Date" even when the Responsibility field isn't changing. See below. In this screenshot, I'd expect rows 8-14 to all have Responsibility Set Date = 1/10/2023 3:59:38 PM.
Open to other suggestions - thanks again!
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
22 | |
21 | |
20 | |
14 | |
11 |
User | Count |
---|---|
43 | |
34 | |
25 | |
23 | |
23 |