- Subscribe to RSS Feed
- Mark Topic as New
- Mark Topic as Read
- Float this Topic for Current User
- Bookmark
- Subscribe
- Printer Friendly Page
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
Formula with variables works, while without - doesn't. Why?
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.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
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).
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
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).
Helpful resources
Join us at the Microsoft Fabric Community Conference
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Microsoft Fabric Community Conference 2025
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
Subject | Author | Posted | |
---|---|---|---|
12-24-2023 03:58 PM | |||
Anonymous
| 07-03-2024 11:48 AM | ||
02-06-2023 09:55 AM | |||
08-22-2024 08:32 AM | |||
Anonymous
| 06-14-2023 06:28 AM |
User | Count |
---|---|
128 | |
82 | |
59 | |
57 | |
45 |
User | Count |
---|---|
185 | |
109 | |
82 | |
62 | |
48 |