Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin 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.
Hi All,
This might be a very basic question to many of you. I am trying to create a model where all my transactions carried out in different currencies is translated into USD using montly exchange rates.
My model has three tables, 1) calendar (marked as date table), 2) fact_transaction table (this table has transaction values as well as transation date) and 3) exchange rate table (containing monthly average exchange rates on 1st date of each month against multiple currencies).
Relationship is direct between calendar and transaction date as well as calendar and monthly exchange rate date.
Help to bring clarity would be appreciated.
Solved! Go to Solution.
You could do it as a measure like
USD Amount Measure =
SUMX (
'Transactions',
VAR CurrencyRate =
LOOKUPVALUE (
'Exch rate'[rate],
'Exch Rate'[Date],
DATE ( YEAR ( 'Transactions'[Transaction date] ), MONTH ( 'Transactions'[Transaction date] ), 1 ),
'Exch rate'[Currency], 'Transactions'[Currency]
)
RETURN
'Transactions'[Amount] * CurrencyRate
)
but I think performance would likely be better having a calculated column and then building measures based on that. If it was a column then it would be calculated once, during data refresh, and then you could have measures to perform sum, average etc on the calculated column without having to pay the cost of all the lookups.
Best advice is to try both ways and use DAX Studio to compare performance
You could create a calculated column in the transactions table like
USD Amount =
VAR CurrencyRate =
LOOKUPVALUE (
'Exch rate'[rate],
'Exch Rate'[Date],
DATE ( YEAR ( 'Transactions'[Transaction date] ), MONTH ( 'Transactions'[Transaction date] ), 1 ),
'Exch rate'[Currency], 'Transactions'[Currency]
)
RETURN
'Transactions'[Amount] * CurrencyRate
Hi John,
This did work. But i was wondering if instead of adding conditional column, there was a way to achieve this through dax measures.
Since i intend to add more factual transaction table and as far as i know measures are way better in terms of performance than calculated columns.
You could do it as a measure like
USD Amount Measure =
SUMX (
'Transactions',
VAR CurrencyRate =
LOOKUPVALUE (
'Exch rate'[rate],
'Exch Rate'[Date],
DATE ( YEAR ( 'Transactions'[Transaction date] ), MONTH ( 'Transactions'[Transaction date] ), 1 ),
'Exch rate'[Currency], 'Transactions'[Currency]
)
RETURN
'Transactions'[Amount] * CurrencyRate
)
but I think performance would likely be better having a calculated column and then building measures based on that. If it was a column then it would be calculated once, during data refresh, and then you could have measures to perform sum, average etc on the calculated column without having to pay the cost of all the lookups.
Best advice is to try both ways and use DAX Studio to compare performance
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
10 | |
9 | |
8 | |
8 | |
8 |
User | Count |
---|---|
13 | |
12 | |
11 | |
10 | |
8 |