Dynamic Currency Conversion in Power BI with DAX

Requirement

A common scenario in multinational companies is having to integrate different currency rates across transactional data.

Quite often sales data is stored regardless of the currency, so the currency code related to each sale is also stored in another column.

So, what we need to do is to integrate the whole daily historical exchange rates for every single currency used within the company.

Then a common approach is to convert through the ETL process all the sales data into one single currency usually USD obviously it can vary from one company to another. This is always a good practice to hold only one single currency in the DWH as it makes it much easier to apply all the business calculation rules.

Let’s assume that in our case we convert all the sales into USD.

However, large international companies have offices and firms all over the world and thus need financial dashboards and reports to be in their different offices’ local currencies.

So, one solution can be to create a dynamic currency conversion measure in Power BI so we can display the USD amount into any needed currencies.

Below I outline how we can solve this particular requirement in a few simple steps:

Modeling

The fact CurrencyRate stores the daily historical exchange rates .
The dimension Currency links the currencies to the fact Currency Rates.
The dimension links the fact Currency Rate and the fact Internet Sales with the date attribute.

Note that if you want to hold and handle multiple currencies in your DWH you’ll need to duplicate the dim Currency, one used as a filter (with a direct link to the fact) and another as conversion calculator like in our scenario (with no link to the fact Sales)

DAX Measure

SalesAmountCurrency = 
   
var _USDMeasure =sum(v_FactInternetSales[SalesAmount])
return
if(ISBLANK(_USDMeasure),blank(),
    if(HASONEFILTER(v_DimCurrency[CurrencyName]),
-- the conversion calculation starts here 
-- the above part is just used to handle null values
-- and slicer with multiple values allowed
        var _sumx =sumx(
        CROSSJOIN(
                    values(v_DimCurrency[CurrencyKey]),
                    values(DimDate[DateKey])
                ),
            CALCULATE(
            var _USDMeasurex =sum(v_FactInternetSales[SalesAmount])
            return
            Divide(_USDMeasurex,VALUES(FactCurrencyRate[AverageRate]))
            )
        )
        return 
        _sumx,_USDMeasure
    )   
)

So this measure simply computes the conversion calculation row-by-row and as you will see in the result section the conversion will be calculated on the fly as we switch from one currency to another.

Result

As you can see the sales amount gets automatically converted into the selected currency.

Make things look nicer

We can also use the above measure and concatenate the currency code with Sales Amout to automatically display the code currency with the sales amount

SalesAmountCurrencyCode = 
   
var _USDMeasure =sum(v_FactInternetSales[SalesAmount])
return
if(ISBLANK(_USDMeasure),blank(),
    if(HASONEFILTER(v_DimCurrency[CurrencyName]),
        var _sumx =sumx(
        CROSSJOIN(
                    values(v_DimCurrency[CurrencyKey]),
                    values(DimDate[DateKey])
                ),
            CALCULATE(
            var _USDMeasurex =sum(v_FactInternetSales[SalesAmount])
            return
                Divide(_USDMeasurex,VALUES(FactCurrencyRate[AverageRate]))
            )
        )
        return 
        if(ISBLANK(_sumx),
            blank(),
            concatenate(CONCATENATE(FIRSTNONBLANK(v_DimCurrency[CurrencyAlternateKey],1), " "),FORMAT( _sumx, "Standard")  )
        ),concatenate("USD ",FORMAT( _USDMeasure, "Standard") )
    )   
)

Note that the format type of this measure is now text.
Therefore, we can no longer simply reference this measure in another measure that would require advanced calculation such as ratio, YTD, projection and so on.
Also, if your users use Excel or want to export the PBI visual into Excel, it won’t work as the figures are in text format.

The sample data used in this post is from AdventureWorksDWH2014.

DAX – Exclude data based on Slicer selection

How works a slicer in Power BI?

A slicer is just like a filter, it is used to narrow a portion of data shown in a visual.
For example if we want to narrow my dataset to only specific regions we just need to tick the region we want to see and all the unticked regions will not show up in our visual.

So a normal slicer includes the selected items and excludes the unselected items. But what if instead of including the selected items we want to exclude them.

How to exclude data from a Slicer selection?

In other words, we want to use a slicer to exclude some data and display all the others.

Step 1:
First, we need to create a disconnected dimension which will be a copy of the dimension used as a slicer, “DimSalesTerritory” in my case.

Step 2:
We then need to create a measure “isExclude” that will be used to find out which rows should be excluded if any.

isExclude = 
IF(
    MAX(DimSalesTerritory[SalesTerritoryRegion]) IN 
    ALLSELECTED('Disconected DimSalesTerritory'[SalesTerritoryRegion]) 
    &amp;&amp; COUNTROWS(ALLSELECTED('Disconected DimSalesTerritory')) <> 
    COUNTROWS(ALL('Disconected DimSalesTerritory')),
    1,
    0
)

The first condition checks which rows should be excluded and the second condition is only used to prevent the measure to exclude everything when nothing is selected.

Step 3:
Now we can create a new measure “Sales Amount (Disconnected)” which will sum up the SalesAmount for all the regions that are not excluded.

Sales Amount (Disconected) = 
VAR FilterRegions = 
    FILTER (
        FactInternetSales,
        [isExclude] =0
    )
RETURN
    CALCULATE (
        sum(FactInternetSales[SalesAmount]), 
        FilterRegions 
    )

Step 4:
All right, you should be all set up now now.
As we can see on the visuals below when we select Australia from the slicer all the other regions appart from Australia are displayed.

Step 4 bis:
If instead of creating a new measure you want the “Exclude Slicer” to work on your visual for any measures you just need to add the “isExclude” measure into the visual filter pane.

Visual level filters for slicers

Since the latest Power BI release (June 2019) we are now able to filter a slicer based on a measure!
And I think we’ve all been waiting for this feature for quite a while.

One of the top reason we needed this feature was to have the ability to sync slicers. (Well this was already achievable with the bidirectionnel filter which is a really bad practice…)
So as we can see on the example below the customer Alma has bought only three products but the whole list of products is still showing up in the slicer Product.

So how can sync the slicers and make sure only the sold products apear in the slicer?
This is pretty simple we only need to have a measure and not a column and drag this measure into the visual filter area of the slicer.

Once we have dragged the measure into the visual filter pane the slicer will only show the sold products.

And if we want to filter a slicer based on more than one measure we can simply create a measure that will check the not null condition on multiple measures and returns 1 if at least one the measure is not null. And then drag this filterMeasure into the visual filter area to sync our slicers.

filterMeasure= 
if(not(ISBLANK([Order Qty])) || not(ISBLANK([Sales Amount])) ,1,0)

Visualising Deviation From Average in Power BI

Note that throughout this article I will use the margin measure to illustrate the deviation from average application but the same pattern can be applied to any measures like Sales volume, Delivery time, Profit, etc…

Margin is a key metric to asses high level performance of a company.
But sometime we want to measure and compare specific shop or department or employee performance with the entire company over all performance and this where deviation from average metric comes to help.

The requirement are as follows:

  • Company overall margin over time (which is just the margin average)
  • Employee margin over time
  • Employee margin deviation from the company margin average over time
  • Employee margin deviation vs Last Year Employee margin deviation

And the final result should look like this:

Capture2

Now let’s define our measures:


 

Margin  and Overall Margin calculation

Margin:

Margin % = divide(([Total Revenue]-[Total COGS]),[Total COGS])

Overall Margin:

All Margin =
if(
    ISBLANK([Margin %]),
    BLANK(),
    calculate([Margin %],ALLEXCEPT('Fact','Date')
)

Removes all context filters except filters that have been applied to the fact or date tables.

Margin Deviation From Average measures

Margin Deviation From AVG:

Margin Deviation =
var _AllMargin = calculate([Margin %],ALLEXCEPT('Fact','Date'))
Return
IF(ISBLANK([Margin %]),
   BLANK(),
   [Margin %] - _AllMargin
)

Margin Deviation CY vs LY (Hidden):

Margin Deviation CY vs LY (hidden)=
var _MarginDeviationLY = CALCULATE([Margin Deviation],SAMEPERIODLASTYEAR('Date'[Date])
)
var _MarginDeviationCYvsLY = [Margin Deviation] - _MarginDeviationLY
Return
IF(ISBLANK(_MarginDeviationLY),
   BLANK(),
   IF(_MarginDeviationCYvsLY>0,
      1,
      0
     )
  )

Margin Deviation CY vs LY:

Margin Deviation CY vs LY =
IF(ISBLANK([Margin Deviation CY vs LY (hidden)]),
   BLANK(),
   IF([Margin Deviation CY vs LY (hidden)>0,
      UNICHAR(9650),
      UNICHAR(9660)
     )
  )

Unichar is a great function which returns the Unicode character referenced by the numeric value, we can draw really cool stuff with this function.
(UNICHAR(9650) Up-Arrow , UNICHAR(9660) Down-Arrow)


Visualising everything together

Now let’s put together our measures into a matrix visual:

  • Margin %: Margin by employee and by year
  • All Margin: Yearly margin of the entire company
  • Margin Deviation: This is simply the difference between the employee margin and the average margin of the entire company
  • Margin Deviation CY vs LY: Current Year Margin Deviation versus Last Year Margin Deviation
Capture3

How do we read this result:

Andrew Ma:
In 2013 the entire company margin AVG was 46.9% and Andrew margin was 35.46% hence below the AVG margin by -11.46%.
In 2014 the AVG margin is 74.32% and Andrew has now performed better than the AVG margin by 8.42%.
Note that Andrew has also increased his margin Deviation by nearly 20% (8.42–11.44) so he got a up arrow.

Tina Lassila:
In 2013 Tina realised a Margin% of 101.44% and she beat the AVG margin by 54.54%.
In 2014 Tina realised a Margin% of 116.67% which is a nice increase compared to 2013!
However, it turns out that the whole company performed better in 2014…
So if we look at Tina’s Margin Deviation compared to the last year we notice that she did not perform as good as in 2013 ans thus got a down arrow.

A nicer visual

Capture2
Capture5

To get this visual we just need to keep the previous matrix above, remove the first two columns and then apply some conditional formatting using the Margin Deviation CY vs LY (hidden) measure.
And by looking at this visual we can clearly observe that Tina performance compare to the AVG Margin has decreased by around 10%.

In most cases the margin indicator is used to asses people, team or product performance.
However, by using the Margin only we’re missing out the overall trend of the company.  At first sight an increase of 15% seems great but once we realise that the overall increase was actually of 28% it doesn’t seem great anymore.

This is why margin deviation from average can provide really great insight from our data but using it alone could also be misleading as even if Tina Margin Deviation is not that good she’s still the best performer for the year of 2014.
So I think combining the Margin% and Margin Deviation from average measures together is always a good idea!

Here is the power BI Customer Profitability sample that I used for this article.