Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Can someone please guide me why does my formula work in the form containing variables, but when I move their contents back into the formula, it doesn't?
The form containing variables:
Result =
var _parent = [Parent]
var _maxvalue =
CALCULATE(
MAX(Table1[Value]),
ALLEXCEPT(Table2,Table2[Parent])
)
return
CONCATENATEX(
CALCULATETABLE(
FILTER(
ALL(Table1),
Table1[Value] = _maxvalue &&
RELATED(Table2[Parent]) = _parent
)
),
[Name],","
)
The form without variables:
Result2 =
CONCATENATEX(
CALCULATETABLE(
FILTER(
ALL(Table1),
Table1[Value] = CALCULATE(
MAX(Table1[Value]),
ALLEXCEPT(Table2,Table2[Parent])
)
&& RELATED(Table2[Parent]) = [Parent]
)
),
[Name],","
)
Solved! Go to Solution.
In the first example with the variables the value of the variables is evaluated once and captured, then the rest of the expression is evaluated.
In the second expression without the variables both the [Parent] measure and the MAX() expression are re-evaluated for each row of Table1 (since they are referenced inside the FILTER function which effectively iterates row by row over Table1). This may or may not affect the [Parent] measure depending on your data and how the two tables are related, but it will definitely have a big impact on the calculation of MAX( Table1[Value] ).
Effectively as the FILTER function iterates row by row over Table1 it calculates the MAX of Table1[Value] for that row which gives you the current value for that row. This in turn will return every row in Table1 as you are effectively checking if the amount in the [Value] column is equal to itself. You could probably fix this by adding an ALL(table1) as a parameter in your calculation of the MAX(), but personally I find using variables simpler (and they perform better also).
In the first example with the variables the value of the variables is evaluated once and captured, then the rest of the expression is evaluated.
In the second expression without the variables both the [Parent] measure and the MAX() expression are re-evaluated for each row of Table1 (since they are referenced inside the FILTER function which effectively iterates row by row over Table1). This may or may not affect the [Parent] measure depending on your data and how the two tables are related, but it will definitely have a big impact on the calculation of MAX( Table1[Value] ).
Effectively as the FILTER function iterates row by row over Table1 it calculates the MAX of Table1[Value] for that row which gives you the current value for that row. This in turn will return every row in Table1 as you are effectively checking if the amount in the [Value] column is equal to itself. You could probably fix this by adding an ALL(table1) as a parameter in your calculation of the MAX(), but personally I find using variables simpler (and they perform better also).
User | Count |
---|---|
63 | |
59 | |
56 | |
38 | |
29 |
User | Count |
---|---|
82 | |
62 | |
45 | |
41 | |
40 |