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

Be 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

Reply
FaizanRao
New Member

Exchange Rate Conversion with Date Range

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 

pbix file 

 

Thanks for your help

 

Faizan Rao

 

2 ACCEPTED SOLUTIONS
selimovd
Super User
Super User

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

 

If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍
 
Best regards
Denis
 

 

View solution in original post

v-rzhou-msft
Community Support
Community Support

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.

1.png

If we select Currency in slicer, such as USD, measures will show values in USD rate and USD rate in date range.

2.png

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.

View solution in original post

5 REPLIES 5
v-rzhou-msft
Community Support
Community Support

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.

1.png

If we select Currency in slicer, such as USD, measures will show values in USD rate and USD rate in date range.

2.png

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.

FaizanRao
New Member

also suggest how I could display exchange rate in table.

FaizanRao
New Member

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?

 

updated pbix file 

 

Thanks

 

Faizan

selimovd
Super User
Super User

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

 

If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍
 
Best regards
Denis
 

 

Sorry for my late reply. Once again thanks for your help.

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.