March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Dear Members
I'm a newbie and need help to convert base currency values in USD or any other currency.
I have posted the same question earlier but provided solution is not working when I copied the suggested formula to my database.
Data Tables & Required Results
Thanks for your help
Faizan Rao
Solved! Go to Solution.
Hey @FaizanRao ,
first of all you have to fix the data type in the CurrencyRate table. The value should be a decimal number, the dates should be dates.
Then you can add the following calculated column to the SalesData table:
Value in CurrencyRate =
VAR vRowCurrency = SalesData[Currency]
VAR vRowDate = SalesData[Date]
VAR vRowValue = SalesData[Value]
VAR vExchangeRate =
CALCULATE(
MAX( CurrencyRate[Value] ),
ALL( CurrencyRate ),
CurrencyRate[Attribute] = vRowCurrency
&& CurrencyRate[Date From] <= vRowDate
&& CurrencyRate[Date To] >= vRowDate
)
RETURN
vRowValue * vExchangeRate
Hi @FaizanRao
We couldn't show dynamc results in calcualted columns, try to build a measure to show dynamic results in table visual by slicer.
Firstly we build an unrelated Currency table by dax.
CurrencySlicer = VALUES(CurrencyRate[Currency])
Build a slicer by this table. Then create measures.
Value in Select Currency Rate =
VAR _CurrencyRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = MAX ( SalesData[Currency] )
)
)
VAR _SelectCurrency =
SELECTEDVALUE ( CurrencySlicer[Currency] )
VAR _SelectRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = _SelectCurrency
)
)
RETURN
IF (
HASONEFILTER ( CurrencySlicer[Currency] ),
DIVIDE ( SUM ( SalesData[Value] ), _CurrencyRate ) * _SelectRate,
DIVIDE ( SUM ( SalesData[Value] ), _CurrencyRate )
)
Select Currency Rate =
VAR _SelectCurrency =
SELECTEDVALUE ( CurrencySlicer[Currency] )
VAR _SelectRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = _SelectCurrency
)
)
VAR _RMRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = "RM"
)
)
RETURN
IF ( HASONEFILTER ( CurrencySlicer[Currency] ), _SelectRate, _RMRate )
Result is as below.
By default, measures will show values in RM rate and RM rate in date range.
If we select Currency in slicer, such as USD, measures will show values in USD rate and USD rate in date range.
For more details, you can download my sample as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @FaizanRao
We couldn't show dynamc results in calcualted columns, try to build a measure to show dynamic results in table visual by slicer.
Firstly we build an unrelated Currency table by dax.
CurrencySlicer = VALUES(CurrencyRate[Currency])
Build a slicer by this table. Then create measures.
Value in Select Currency Rate =
VAR _CurrencyRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = MAX ( SalesData[Currency] )
)
)
VAR _SelectCurrency =
SELECTEDVALUE ( CurrencySlicer[Currency] )
VAR _SelectRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = _SelectCurrency
)
)
RETURN
IF (
HASONEFILTER ( CurrencySlicer[Currency] ),
DIVIDE ( SUM ( SalesData[Value] ), _CurrencyRate ) * _SelectRate,
DIVIDE ( SUM ( SalesData[Value] ), _CurrencyRate )
)
Select Currency Rate =
VAR _SelectCurrency =
SELECTEDVALUE ( CurrencySlicer[Currency] )
VAR _SelectRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = _SelectCurrency
)
)
VAR _RMRate =
CALCULATE (
SUM ( CurrencyRate[Rate] ),
FILTER (
ALL ( CurrencyRate ),
CurrencyRate[Date From] <= MAX ( SalesData[Date] )
&& CurrencyRate[Date To] >= MAX ( SalesData[Date] )
&& CurrencyRate[Currency] = "RM"
)
)
RETURN
IF ( HASONEFILTER ( CurrencySlicer[Currency] ), _SelectRate, _RMRate )
Result is as below.
By default, measures will show values in RM rate and RM rate in date range.
If we select Currency in slicer, such as USD, measures will show values in USD rate and USD rate in date range.
For more details, you can download my sample as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
also suggest how I could display exchange rate in table.
Dear Denis
Thanks for your help.
Now I could get conversion in RM currency but pls help me how I could convert in any other currency like USD or SGD?
Thanks
Faizan
Hey @FaizanRao ,
first of all you have to fix the data type in the CurrencyRate table. The value should be a decimal number, the dates should be dates.
Then you can add the following calculated column to the SalesData table:
Value in CurrencyRate =
VAR vRowCurrency = SalesData[Currency]
VAR vRowDate = SalesData[Date]
VAR vRowValue = SalesData[Value]
VAR vExchangeRate =
CALCULATE(
MAX( CurrencyRate[Value] ),
ALL( CurrencyRate ),
CurrencyRate[Attribute] = vRowCurrency
&& CurrencyRate[Date From] <= vRowDate
&& CurrencyRate[Date To] >= vRowDate
)
RETURN
vRowValue * vExchangeRate
Sorry for my late reply. Once again thanks for your help.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
114 | |
76 | |
57 | |
52 | |
44 |
User | Count |
---|---|
163 | |
116 | |
63 | |
58 | |
50 |