cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Helper I
Helper I

Create a measure of the ratio of value in same column by different groups in different columns

 

I have below data. 

 

Items 1-5 were sold and the cost of them are splitted with below ratio by categories and brands.  The last 2 columns are the working steps and the values are look up from Table 2 & 3 with calculated formula set.  Cost Split (in USD) is the total cost * cost split ratio * exchange rate.

 

I wanna create a measure in Power BI which calculates the ratio of cost split by brands and cost split by categories, i.e. sum of total cost split by brands / sum of total cost split by categories, and the results will be shown in Pivot Table format (Table 4).  For example,  the ratio of Brand E in Cat A is 6 / 11 = 54.5%.  How to set the measure to get the result in Power BI Pivot Table?

 

Table 1 Cost Split of Item Sold

ItemCategoryBrandCost Split RatioCurrencyCost Split (in USD)
Item 1Cat ABrand D0.50HKD5.00
Item 1Cat ABrand E0.30HKD3.00
Item 1Cat BBrand F0.20HKD2.00
Item 2Cat BBrand F0.40JPY4.80
Item 2Cat CBrand D0.60JPY7.20
Item 3Cat ABrand E0.20USD3.00
Item 3Cat CBrand F0.10USD1.50
Item 3Cat BBrand D0.70USD10.50
Item 4Cat CBrand E0.20CNY1.60
Item 4Cat BBrand E0.80CNY6.40
Item 5Cat CBrand F1.00KRW11.00

 

Table 2 Total Cost of Items Sold

ItemCurrencyCost
Item 1HKD77.7
Item 2JPY1262.52
Item 3USD15
Item 4CNY55.6
Item 5KRW13101.77

 

Table 3 Exchange Rate

CurrencyExchange Rate
HKD7.77
USD1
CNY6.95
KRW1191.07
JPY105.21

 

Table 4

 Cat ACat BCat C
Brand D45.5%44.3%33.8%
Brand E54.5%27.0%7.5%
Brand F0.0%28.7%58.7%

 

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support
Community Support

Re: Create a measure of the ratio of value in same column by different groups in different columns

Hi @trinachung 

Create a measure

Measure =
SUM ( Table1[cost split usd] )
    / CALCULATE (
        SUM ( Table1[cost split usd] ),
        FILTER (
            ALLSELECTED ( Table1 ),
            Table1[Category]
                = MAX ( Table1[Category] )
        )
    )

Capture8.JPG

Best Regards
Maggie
Community Support Team _ Maggie Li
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

3 REPLIES 3
Highlighted
Super User IV
Super User IV

Re: Create a measure of the ratio of value in same column by different groups in different columns

New columns in table 1

Total cost = maxx(filter(table2,table1[item]=table2[item] && table2[Currency] = table1[Currency]),table2[Cost])
exchange rate =maxx(filter(table3,table3[Currency] = table1[Currency]),table3[Exchange Rate])
Cost Split (in USD) = [Total cost] * [cost split ratio] * [exchange rate]

 

Appreciate your Kudos.



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
My Recent Blog -Week is not so Weak Connect on Linkedin

Proud to be a Super User!

Community Support
Community Support

Re: Create a measure of the ratio of value in same column by different groups in different columns

Hi @trinachung 

Create a measure

Measure =
SUM ( Table1[cost split usd] )
    / CALCULATE (
        SUM ( Table1[cost split usd] ),
        FILTER (
            ALLSELECTED ( Table1 ),
            Table1[Category]
                = MAX ( Table1[Category] )
        )
    )

Capture8.JPG

Best Regards
Maggie
Community Support Team _ Maggie Li
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

Highlighted
Helper I
Helper I

Re: Create a measure of the ratio of value in same column by different groups in different columns

Thanks for the solution, Maggie!

Helpful resources

Announcements
August 2020 Community Challenge: Can You Solve These?

August 2020 Community Challenge: Can You Solve These?

We're excited to announce our first cross-community 'Can You Solve These?' challenge!

Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Upcoming Events

Upcoming Events

Wondering what events you could join or have an event to promote yourself? Check out our Upcoming Events.

Community Summit Australia – Join Online!

Community Summit Australia – Join Online!

Be a part of the leading Microsoft Business Applications digital event, curated for the APAC community.

Top Solution Authors
Top Kudoed Authors