Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
Sorry if this has been answered before I could not find any info on it.
I would like to know if it is allowed / possible to use variables inside an iterator.
Basically I would like to grab some value from current row inside the SUMX and store that in a variable, primarily because It would make the code readability much better imo.
Basically I want to reassign the value inside the iterator because it has row context.
Am I right in presuming that If I assign a variable outside the SUMX it will not update itself for each row in the SUMX following it?
So could I do something similar to this?
MyMeasure = SUMX(
-- where would the variables? like this...?
VAR currRowExchangeRate = 'myTable'[transactionCurrencyCode]
-- and more code inside the SUMX here...
) -- sumx end
I cant find any way of doing it when I much around in Power BI.
If you guys know a way of storing the current row value in a variable in ANY way when using iterators, please let me know and give an example. If not at all possible please let me know that too?
Thanks in advance!
Solved! Go to Solution.
Thanks for pointing me in the right direction 🙂
It turns out you CAN put variables inside iterators, you just need to put them after the first argument.
This is great because it can greatly enhance readability
(if you are wondering what all the semicolons ; are about in the code, its because of language settings, its the same as a comma , in us versions)
So like this:
SUMX( tableName;
-- put vars here:
VAR myVariable = tableName[somevalue]
VAR myOtherVariable = tableName[someothervalue]
-- after vars, put the RETURN:
RETURN
-- then use the variables in making the return calculations:
myVariable * myOtherVariable
)
---------
Heres an example from what I was working on:
SUMXVARS =
VAR toCurrency = [Selected Currency] -- from slicer
VAR currencyRatePeriod = [Selected Currency Rate Period] -- from slicer
RETURN
SUMX( 'dummy sales data';
VAR currRowAmount = 'dummy sales data'[amount]
VAR currRowTransactionCurrency = 'dummy sales data'[transaction currency]
VAR currRowDate = 'dummy sales data'[date]
-- depending on user chosen rate period, we change the date to look for
VAR targetCurrencyDate = SWITCH(currencyRatePeriod;
"daily"; currRowDate;
"monthly"; DATE( YEAR(currRowDate); Month(currRowDate);1);
"yearly"; DATE( YEAR(currRowDate); 1;1))
VAR currencyRate = IF('dummy sales data'[transaction currency] = toCurrency;
-- from -> to currency is the same, therefore rate is ALWAYS 1
1;
-- from -> to currency is different, we need to convert
-- go find the right exchange rate value:
LOOKUPVALUE(currencyModel[rate]; currencyModel[from currency code]; currRowTransactionCurrency ;
currencyModel[to currency code]; toCurrency;
currencyModel[date]; targetCurrencyDate;
currencyModel[rate period]; currencyRatePeriod)
)
RETURN
currRowAmount * currencyRate
)
in this article one of the examples has variables defines within ADDCOLUMN, followed by RETURN
https://www.sqlbi.com/articles/variables-in-dax/
so your example would be like this (no clue if it works though)
MyMeasure =
SUMX(
-- where would the variables? like this...? VAR currRowExchangeRate = 'myTable'[transactionCurrencyCode] RETURN
currRowExchangeRate * 2 -- and more code inside the SUMX here... ) -- sumx end
other than that you can try using GROUPBY with CURRENTGROUP
https://msdn.microsoft.com/en-us/query-bi/dax/groupby-function-dax#currentgroup
Thanks for pointing me in the right direction 🙂
It turns out you CAN put variables inside iterators, you just need to put them after the first argument.
This is great because it can greatly enhance readability
(if you are wondering what all the semicolons ; are about in the code, its because of language settings, its the same as a comma , in us versions)
So like this:
SUMX( tableName;
-- put vars here:
VAR myVariable = tableName[somevalue]
VAR myOtherVariable = tableName[someothervalue]
-- after vars, put the RETURN:
RETURN
-- then use the variables in making the return calculations:
myVariable * myOtherVariable
)
---------
Heres an example from what I was working on:
SUMXVARS =
VAR toCurrency = [Selected Currency] -- from slicer
VAR currencyRatePeriod = [Selected Currency Rate Period] -- from slicer
RETURN
SUMX( 'dummy sales data';
VAR currRowAmount = 'dummy sales data'[amount]
VAR currRowTransactionCurrency = 'dummy sales data'[transaction currency]
VAR currRowDate = 'dummy sales data'[date]
-- depending on user chosen rate period, we change the date to look for
VAR targetCurrencyDate = SWITCH(currencyRatePeriod;
"daily"; currRowDate;
"monthly"; DATE( YEAR(currRowDate); Month(currRowDate);1);
"yearly"; DATE( YEAR(currRowDate); 1;1))
VAR currencyRate = IF('dummy sales data'[transaction currency] = toCurrency;
-- from -> to currency is the same, therefore rate is ALWAYS 1
1;
-- from -> to currency is different, we need to convert
-- go find the right exchange rate value:
LOOKUPVALUE(currencyModel[rate]; currencyModel[from currency code]; currRowTransactionCurrency ;
currencyModel[to currency code]; toCurrency;
currencyModel[date]; targetCurrencyDate;
currencyModel[rate period]; currencyRatePeriod)
)
RETURN
currRowAmount * currencyRate
)
User | Count |
---|---|
89 | |
82 | |
53 | |
40 | |
35 |