Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
Zyg_D
Continued Contributor
Continued Contributor

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],","
)

 

 

1 ACCEPTED SOLUTION
d_gosbell
Super User
Super User

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).

View solution in original post

1 REPLY 1
d_gosbell
Super User
Super User

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

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.