DAX measure using values across tables...

Matty

Well-known Member
Joined
Feb 17, 2007
Messages
3,717
Hi,

Looking for some help!

Data set up as follows...

Table 1 (sales data)

IDProductDCMonthSales
Apple1Apple111500
Pear1Pear1150
Orange1Orange1130
Apple1Apple121200
Pear1Pear1225
Orange1Orange1260

<colgroup><col><col span="3"><col></colgroup><tbody>
</tbody>

Table 2 (conversion data)

IDProductDCDenominatorNumerator
Apple1Apple1115
Pear1Pear125
Orange1Orange112
Apple2Apple2130
Pear2Pear2210
Orange2Orange214

<colgroup><col><col span="2"><col><col></colgroup><tbody>
</tbody>

There is a relationship between Table 1 and Table 2 via the ID column (a concatenation of 'Product' and 'DC').

I want a measure to convert the sales data in Table 1 using the relevant denominator and numerator in Table 2. In simple terms, the formula would be:

Code:
=SUM(Table1[Sales]) * Table2[Denominator] / Table2[Numerator]

The problem I can't get my head around is how to get the formula to use the correct row from Table 2.

The resulting measure should return the values as shown in 'Sales Revised' below:

ProductMonthSales Revised
Apple1100
Pear120
Orange115
Apple280
Pear210
Orange230

<colgroup><col span="2"><col></colgroup><tbody>
</tbody>

Hope someone can help.

Cheers,

Matty
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
You can create a primary key during the ETL Process such as:

pbaapkD.png



Then you can do something like ( numerator and denominator are mixed up by the way )

Code:
Measure = 
IF(
    HASONEVALUE( Conversions[PrimaryKey] ),
    SUM( Sales[Sales] ) * DIVIDE( SELECTEDVALUE( Conversions[Denominator] ), SELECTEDVALUE( Conversions[Numerator] ) )
)


ETkCEvA.png
 
Last edited:
Upvote 0
Hi VBA Geek,

Thanks for your help.

I'd actually come up with the following, which also works:

Code:
SUMX (
    Table1,
    CALCULATE (
        SUM ( Table1[Sales] ) * MIN ( Table2[Denominator] )
            / MIN ( Table2[Numerator] )
    )
)

Although I'd imagine yours is less *expensive*, processing-wise?

Also, as I'm using Excel DAX, SELECTEDVALUE isn't available in there, hence the use of MIN instead, though I don't know if this could have unexpected consequences in certain circumstances.

Obviously, as we can't have multiple joins in Excel (or Power BI), the ID column was necessary to create the one-to-many relationship, so I'm not sure I understand how your Primary Key and Foreign Key concept is going to work here. Could you explain further?

Thanks again...

Matty
 
Last edited:
Upvote 0
Hi Matty

you should always make use of physical relationships whenever possible, it is true you can use DAX to 'create a relationship' on the fly but physical relationships are generally much faster.

In place of SELECTEDVALUE you can use VALUES in this case.

I just created an unique ID per combination of Product and DC instead of concatenating these columns into a new column in order to create the relationship since relationships working on integers are faster
 
Upvote 0
Hi VBA Geek,

Thanks for your suggestion regarding VALUES.

Could you share your method for creating the unique ID in Power Query, please? Interested to understand how you have done it.

Thanks,

Matty
 
Last edited:
Upvote 0
You conversion data table has unique rows so you just need to add an index column which serves are PrimaryKey

Code:
let    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WciwoyEk1VNKBMIC0IQybKsXqRCsFpCYWgbggGipjBMQQSf+ixLx0sG4IC0m7EVgB2FAjJNONoNLGBnDTjRCmG8FUGCAZb4RsPEy/iVJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [ID = _t, Product = _t, DC = _t, Denominator = _t, Numerator = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", type text}, {"Product", type text}, {"DC", Int64.Type}, {"Denominator", Int64.Type}, {"Numerator", Int64.Type}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "PrimaryKey", 1, 1)
in
    #"Added Index"


The other query, once you have loaded also the Sales Table data is just a matter of join:



Code:
let
    Source = Table.NestedJoin(#"Sales Data",{"Product", "DC"},#"Conversion Data",{"Product", "DC"},"Conversion Data",JoinKind.Inner),
    ExpandedConversionData = Table.ExpandTableColumn(Source, "Conversion Data", {"PrimaryKey"}, {"ForeignKey"}),
    RemovedOtherColumns = Table.SelectColumns(ExpandedConversionData,{"ForeignKey", "Month", "Sales"})
in
    RemovedOtherColumns
 
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,949
Members
448,534
Latest member
benefuexx

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top