cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Frequent Visitor

Allocation Totals by country and region

Hi,

 

I have a dataset where Country and Region are both coming into a single column and a lookup table that has both separated into two, along with an allocation %. Is there a way where I can do a sum by Country and add their corresponding allocation amount based on Table B? Table A is joined to Table B on Location = Country.

 

Table A

LocationExpense
Mexico100
USA1000
North America20000
South America1000

 

Table B

CountryRegionRegion %
USANorth America55%
MexicoNorth America25%
CanadaNorth America20%

 

In this example, I'm looking to generate a result set that contains the following:

CountryExpenseAllocatedTotal Allocation
USA10001100012000
Mexico

100

5000

5100

 

My first attempt was the following: Calculate(sum(expense), allexcept(table A)) * sum(region %). This works to an extent, but when I bring in A.Location, the calculation will apply to both the countries and regions, not just the countries.  

 

Thank you for any insight!

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Community Support
Community Support

Re: Allocation Totals by country and region

Hi @ozne99 ,

 

Or you also can do like this:

Allocated = 
SUMX(
    FILTER(
        'Table A',
        'Table A'[Location] = 'Table B'[Region]
    ),
    'Table A'[Expense] * 'Table B'[Region %]
)

Total Allocation = 
VAR x = 
SUMX(
    FILTER(
        'Table A',
        'Table A'[Location] = 'Table B'[Country]
    ),
    'Table A'[Expense]
)
RETURN
[Allocated] + x

mm4.PNG

 

Best regards,
Lionel Chen

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: Allocation Totals by country and region

As table B only seems to have region and country relations. I created new columns in table B.

Allocated = AVERAGEX(FILTER('Table A','Table A'[Location]='Table B'[Region]),'Table A'[Expense]*'Table B'[Region %])
Expense = maxx(FILTER('Table A','Table A'[Location]='Table B'[Country]),'Table A'[Expense]) 

 

Link : https://www.dropbox.com/s/gqsbbrwd6vw49fo/allocations_regions.pbix?dl=0

 

Appreciate your Kudos. In case, this is the solution you are looking for, mark it as the Solution. In case it does not help, please provide additional information and mark me with @
Thanks. My Recent Blog -
Winner-Topper-on-Map-How-to-Color-States-on-a-Map-with-Winners , HR-Analytics-Active-Employee-Hire-and-Termination-trend
Power-BI-Working-with-Non-Standard-Time-Periods And Comparing-Data-Across-Date-Ranges

Connect on Linkedin

 



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!

Highlighted
Helper I
Helper I

Re: Allocation Totals by country and region

Hey @ozne99 ,
You can create a calculated column by the solution which @amitchandak Post.

Else you can create Measure Also,

Allocation Measure =
CALCULATE(SUM('Table A'[Expense])*SUM('Table'[Region %]),FILTER('Table A','Table A'[Location] IN FILTERS('Table'[Region]) ))
 
Expense Measure = CALCULATE(SUM('Table A'[Expense]),FILTER('Table A','Table A'[Location] IN FILTERS('Table'[Country]) ) )
 
Hope it will help.
Regards,
snandy
 
 
Highlighted
Community Support
Community Support

Re: Allocation Totals by country and region

Hi @ozne99 ,

 

Or you also can do like this:

Allocated = 
SUMX(
    FILTER(
        'Table A',
        'Table A'[Location] = 'Table B'[Region]
    ),
    'Table A'[Expense] * 'Table B'[Region %]
)

Total Allocation = 
VAR x = 
SUMX(
    FILTER(
        'Table A',
        'Table A'[Location] = 'Table B'[Country]
    ),
    'Table A'[Expense]
)
RETURN
[Allocated] + x

mm4.PNG

 

Best regards,
Lionel Chen

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

Helpful resources

Announcements
Community Blog

Community Blog

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

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors