다음을 통해 공유


Currency Conversion in SSAS 2012 (Multidimensional & Tabular)

Types of Currency Conversion

As defined by the Business Intelligence Wizard in Multidimensional, there are 3 types of currency conversion.

  • One-to-many.  In this case we store the transactions (for example in the data warehouse) in a single base currency.  Even if they originally took place in different countries, we can convert to a single currency in the ETL.  The cube or tabular model will then convert to the reporting currencies.
  • Many-to-many.  Here we store the transactions in the original, different currencies.  The cube or tabular model now has (roughly) twice as many calculations that need to be performed.  First convert to a single “pivot” currency, and then to the reporting currencies.
  • Many-to-one.  Again (like many-to-many), we store the transactions in the original, different currencies.  However, in this case there is no business requirement to report in different reporting currencies.  We just choose not to utilize the ETL to convert to a base currency.  Instead, the cube or tabular model is used for this purpose.

The most common of these, in a data warehousing environment at least, is one-to-many.

Business Requirement

The primary business requirement is that users can view all transactions in any of the supported reporting currencies.  As a secondary requirement, the user may also be interested in what country/currency the original transaction took place.

Even the secondary requirement can be delivered by one-to-many.  We can achieve this by storing the lineage of the original currency in the model and report on it as required.

This article will therefore focus on one-to-many.  Apart from being the most common form of currency conversion, the techniques used for the other 2 types (many-to-many and many-to-one) are basically variations of the techniques used by one-to-many.

Extra Columns in Currency Dimension Table

As a prerequisite to the examples in this article, the following 2 columns are added to the DimCurrency table in AdventureWorksDW.  LCID is used for multidimensional and FormatString is for tabular.

The LCIDs are available here: http://www.microsoft.com/globaldev/reference/lcid-all.mspx

Tip: an easy way to get the format strings is in the tabular-model designer in SSDT, select Format=Currency and set the currency symbol in the properties window of SSDT.  This internally sets the FormatString property to the custom string.

Multidimensional

Consider the following DSV on top of AdventureWorksDW, which includes DimTime, FactInternetSales, FactCurrencyRate and DimCurrency, it should look something like this.

We are only concerned with one of the 3 relationships between Internet Sales Facts and Date (the one based on OrderDateKey).

Consider the following statements.

ð  For a particular date, there will be many exchange rates; one for each of the supported reporting currencies

ð  For a particular currency, there will be many exchange rates; one for each of the dates in the date range for which we are loading data.  Exchange rates change over time.

ð  Therefore, the correct way to model this is with a many-to-many dimension between Internet Sales and Currency.  This will be shown below when we refer to the Dimension Usage tab.

The only measures in the (simplified) cube are Sales Amount (from Fact Internet Sales) and End Of Day Rate (from Currency Rate).  End Of Day Rate has an AggregateFunction property value of “LastNonEmpty”.  LastNonEmpty is defined as a semi-additive measure.  This means it will sum for all dimensions except Date.  For the Date dimension, it will take the last non-empty child.  For example, the exchange rate we would want to see for a week member in a report would not be the sum of the exchange rate on Monday + exchange rate on Tuesday + exchange rate on Wednesday, …  Instead, we just want the most recent exchange rate (maybe exchange rate on Saturday).

The Date attribute in the Date dimension is the key attribute.  It has a KeyColumns property of DateKey (which is the surrogate key of the DimTime table) and a NameColumn of SimpleDate (what the users see at Date level).

If we use the Dimension Wizard to create the Date dimension, it makes it easy to flag with Type = Date, etc.  This is one of the few cases where having these properties set correctly actually affects cube behavior.  For example, semi-additive measures and some MDX functions like YTD won’t work without Type = Date.

Here are the mappings in the Dimension Usage tab.  They are pretty straightforward.  There is a many-to-many relationship between Currency and Fact Internet Sales.

Here is a screenshot of the Currency dimension.  The main points about the Currency dimension are as follows.

  • The KeyColumns property of the Currency attribute is set to CurrencyKey (which is the surrogate key in for the DimCurrency table in AdventureWorksDW).
  • The NameColumn property of the Currency attribute is set to CurrencyName (which is what we want the users to see).
  • The Type property of the dimension (not attribute) is set to Currency.  The only purpose of this (unlike Type=Time that does affect cube behaviour) is to inform client tools in case they want to display currency dimensions differently to regular dimensions.
  • The Type property of the Currency attribute is set to CurrencyName.  Again, this is just to inform client tools.
  • The IsAggregatable property of the Currency attribute is set to False.  This removes the All level for the attribute. We would after all not want to sum the values of different currencies.  500 pounds sterling plus 100,000 cruzeiros does not make any sense.
  • Set the DefaultMember property of the Currency attribute to whatever the Sales Amount values are stored in.  In the case of AdventureWorksDW, it is US Dollars.
  • The ValueColumn property is set to LCID, which is an extra column on the Currency table.  See section below on currency formats for an explanation of this.

Next we need to perform the conversion calculation itself.  There are various options here, some of which are better than others.

  • Measure expressions
  • MDX script cell assignments (which is how the SSAS Multidimensional BI Wizard does it)
  • MDX script calculated members
  • Performing the conversion in the MDX client queries

Measure expressions are arguably the best way to perform currency conversion in Multidimensional.  They tend to perform better than the other options.  Hence this article will use the measure expressions option to perform the conversion calculation.

Measure Expressions

The Sales Amount measure has the following measure expression: “[Sales Amount] / [End Of Day Rate]”.  The facts are stored in US Dollars and the base currency is US Dollars.  The measure expression is a division rather than a multiplication because this is the way the exchange rates are stored in AdventureWorks.  For example, the exchange rate for GBP is roughly 1.5 in the FactCurrencyRate table.  Therefore, to convert $15 from the pivot currency to GBP, 15 / 1.5 gives us 10.  Doing a multiplication would result in £22.50 (obviously wrong).

Note: measure expressions are performed at leaf level.

Back in the Dimension Usage tab, it is worth setting the DirectSlice property of the many-to-many relationship.  Setting it to “([Currency].[Currency].&[100])” means that, when querying Sales Amounts by the base/pivot currency (US Dollars), SSAS has the option to just return the value as it appears in the fact table – i.e. without applying the measure expression.  After all, there is no need to convert US Dollars into US Dollars!  This gives SSAS the option of using DirectSlice as a performance optimization.

We need a tuple with the default member for every enabled attribute in the outer many-to-many dimension.  Incidentally, this is what the Root(<dimension_expression>) function would return, but we can’t use any MDX functions in the DirectSlice property (hence the Functions pane is disabled), so we have to explicitly list each default member in a tuple.

Note: SSAS may choose not to use the DirectSlice optimization (depending on internal algorithms beyond the scope of this article).  Therefore, we still need to ensure the FactCurrencyRate table has an exchange rate of 1 for converting US Dollars into US Dollars – and for every single day for which we have data.  Otherwise, Analysis Services would be looking for an End Of Day Rate to divide by, find null and return null.

Currency Format

Lastly, we need an MDX script cell assignment (in the Calculations tab) to set the Locale ID for currencies.  This will avoid displaying 500 pounds sterling as “$500”.  For a complete list of the Locale IDs, see http://www.microsoft.com/globaldev/reference/lcid-all.mspx

Language([Currency].[Currency].[United Kingdom Pound]) = 2057;
Language([Currency].[Currency].[Brazilian Real]) = 1046;
Language([Currency].[Currency].[US Dollar]) = 1033;

The above assignments are for illustration purposes only.  The main problem with this approach is maintainability.  If we bring in new currencies in the future, we need to modify the MDX script.  The ideal would be to store them in the DimCurrency table, expose them using the ValueColumn property of the Currency attribute, and use that for the assignment.

Language(([Currency].[Currency].Members, [Measures].[Internet Sales Amount])) =
[Currency].[Currency].CurrentMember.MemberValue;

Note: the ValueColumn property of the dimension can be used as a form of “property bag” to store additional information for each dimension member.

Note: the MDX MemberValue (or Member_Value) function will …

  • If no ValueColumn property is specified, it will return the value from NameColumn
  • If no ValueColumn and NameColumn property, it will return the value from KeyColumn

Now if we run a query we should get back correct numbers with the conversion calculation applied at leaf level, and displayed using foreign currency formats.

Note: the values in this screenshot are not the actual numbers that ship with AdventureWorks.

Tabular

The tabular modeling experience is much simpler than multidimensional.  There is nowhere to define the many-to-many relationship, IsAggregatable=False, LastNonEmpty aggregation function, etc.   The tabular modeling experience is basically just a bunch of tables and relationships with fewer options to set properties.  Responsibility for dealing with these features is handed over to DAX.

Here is a DAX query that handles (almost) all the features.  Again, instead of “decorating the meta-data of the model” as we did in multidimensional, responsibility is offloaded to DAX.

DEFINE
MEASURE 'Internet Sales'[Internet Sales] =
    SUMX
    (
        'Currency Rate'
        , CALCULATE( Sum('Internet Sales'[Sales Amount]) /
                     Sum('Currency Rate'[End of Day Rate]) )
    )
MEASURE 'Internet Sales'[Internet Sales FORMATTED] =
    FORMAT
    (
        [Internet Sales]
        , VALUES('Currency'[Format String])
    )
MEASURE 'Internet Sales'[Internet Sales ALL MEMBER DOLLARS] =
    IF
    (
        HASONEVALUE('Currency'[Currency Name])
        , [Internet Sales FORMATTED]
        , [Internet Sales FORMATTED]('Currency'[Currency Name] = "US Dollar")
    )
EVALUATE
ADDCOLUMNS
(
    FILTER
    (
        VALUES('Date'[Calendar Year])
        , [Internet Sales] > 0
    )
    ,"US Dollar", [Internet Sales ALL MEMBER DOLLARS](
        'Currency'[Currency Name] = "US Dollar" )
    ,"United Kingdom Pound", [Internet Sales ALL MEMBER DOLLARS](
        'Currency'[Currency Name] = "United Kingdom Pound" )
    ,"Brazilian Real", [Internet Sales ALL MEMBER DOLLARS](
        'Currency'[Currency Name] = "Brazilian Real" )
    ,"Saudi Riyal", [Internet Sales ALL MEMBER DOLLARS](
        'Currency'[Currency Name] = "Saudi Riyal" )
    ,"ALL MEMBER", [Internet Sales ALL MEMBER DOLLARS]
)
ORDER BY 'Date'[Calendar Year]

Here are some points about this query.

  • All the measures defined could be built into the tabular model for reusability.
  • It is a best practice in DAX to break out calculations into component measures for readability and supportability.  Hence the only measure that would be made visible to the users is “Internet Sales ALL MEMBER DOLLARS” (obviously with a more appropriate name).
  • There are various instances where the shorthand notation for the CALCULATE function is used.  The CALCULATE function allows us to override the filter context.  The following syntax forms are equivalent (the 2nd is the shorthand notation).
    • CALCULATE([Existing Measure],<filter1>,<filter2>…)
    • [Existing Measure](<filter1>,<filter2>…)
  • SUMX is used to create a row context for the rows from the ‘Currency Rate’ table inherited from filter context.  SUMX will iterate each row and apply the conversion calculation at the leaf level.
  • I could not find a way to use LCID in tabular, but we can use the FORMAT function and pass in the FormatString value from the currency table instead.
  • In multidimensional, we can use the following properties to hide the currency all member and choose the default currency of US dollars (summing multiple currencies for the all member obviously doesn’t make sense).
    • IsAggregatable=False removes the all member
    • DefaultMember set to the desired default currency

Given that tabular doesn’t have anything equivalent to these features at this time, we need to check if we are at the all level of the currency dimension using HASONEVALUE(‘Currency’[Currency Name]).  This is equivalent to setting the all member to US dollars.  This also covers the case where a user selects a multi-value filter on currency (for example US dollars and Japanese yen).