Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I am struggling to control different filter context transitions within a complex dax measure. I am trying to compute the median duration for a certain percentile of events, where that percentile is partitioned within a table. My table is structured like this:
index opportunity_id event_order duration status date
109750 | a | 1 | 120 | Active (Not Recruiting) | 24/01/2023 00:00 |
86263 | b | 1 | 361 | Active (Not Recruiting) | 12/07/2022 00:00 |
109752 | a | 2 | 134 | Active (Not Recruiting) | 07/02/2023 00:00 |
86264 | b | 2 | 361 | Active (Not Recruiting) | 12/07/2022 00:00 |
My strategy has been to calculate the target event order (e.g. the one which is the 25th percentile) partitioned by the opportunity_id, and then calculate the median duration for a table filtered to only include records where the event_order = target:
25% Duration (Static) =
VAR _percentile = 0.25
// compute the 25% percentile event order partitioned by opportunity id
VAR _tbl =
ADDCOLUMNS (
'Table',
"@target",
CEILING(
CALCULATE (
MAX ( 'Table'[event_order]),
FILTER (
ALL('Table'),
'Table'[opportunity_id] = EARLIER ( 'Table'[opportunity_id] )
))
* _percentile,
1)
)
VAR _result =
MEDIANX(
FILTER (
_tbl,
[event_order] = [@target]
),
[duration])
RETURN _result
This returns the correct results for all visual types. However, the use of ALL() makes it insensitive to external filtering in the right order, which is desired. For example, if applying a certain filter will remove those records from the _tbl result, when what I need is for the new event order and target to be recalculated dynamically.
To enable dynamic filtering I have tried to re-calculate the event_order dynamically within the measure like so
25% Duration (dynamic) =
VAR _percentile = 0.25
// compute the 25% percentile event order partitioned by opportunity id
VAR _tbl =
ADDCOLUMNS (
'Table',
"@target",
CEILING(
CALCULATE (
MAX ( 'Table'[event_order]),
FILTER (
ALL('Table'),
'Table'[opportunity_id] = EARLIER ( 'Table'[opportunity_id] )
))
* _percentile,
1),
"@event_order",
ROWNUMBER(
ALLSELECTED('Table'),
ORDERBY([event_order], ASC, [index], ASC),
LAST,
PARTITIONBY([opportunity_id])
)
)
VAR _result =
MEDIANX(
FILTER (
_tbl,
[@event_order] = [@target]
),
[duration])
RETURN _result
This returns the correct results in visuals partitioned by opportunty_id (and allows for external filtering) but as soon as I add a date range it becomes inaccurate because it partitions for each date range in the visual. I.e. it returns the 25th percentile for each date range in which it occurs.
Is there any way to control the filter context in such a way that it computes accurate results against timelines (i.e. just one 25th percentile event per opportunity) while still respecting filtering that happens at the reporting layer?
Solved! Go to Solution.
Thanks @v-kongfanf-msft ! I am trying to avoid specifying filters directly in the query. I've ended up getting the query to work in production where I have a relationship to the filtering tables ('Table1') in this example, using a combination of PERCENTILE.INC(), KEEPFILTERS(), and ALLACCEPT()
Hi @cashewNut ,
Try to modify your formula like below:
25% Duration (Adjusted) =
VAR _percentile = 0.25
VAR _filteredTable = FILTER(ALLSELECTED('Table'), [status] = "Active (Not Recruiting)")
VAR _partitionedTable =
ADDCOLUMNS (
_filteredTable,
"@target",
CEILING(
CALCULATE (
MAX ( 'Table'[event_order]),
ALLEXCEPT('Table', 'Table'[opportunity_id])
) * _percentile,
1)
)
VAR _result =
MEDIANX(
FILTER (
_partitionedTable,
[event_order] = [@target]
),
[duration]
)
RETURN _result
Best Regards,
Adamk Kong
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thanks @v-kongfanf-msft ! I am trying to avoid specifying filters directly in the query. I've ended up getting the query to work in production where I have a relationship to the filtering tables ('Table1') in this example, using a combination of PERCENTILE.INC(), KEEPFILTERS(), and ALLACCEPT()
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
25 | |
18 | |
18 | |
17 | |
16 |
User | Count |
---|---|
27 | |
26 | |
19 | |
15 | |
14 |