Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
zubairs
Helper I
Helper I

Cost allocation by branch

Hi Guys,

 

So this is a probelm that I've not been able to resolve for the longest of time.

 

So I have two different data sets, one for revenue and one for cost. The data is calculated by geographic region and follows the hierarchy as such:

 

  • Route (lowest level)
  • Branch
  • Region 
  • Country (highest level)

The costing is done on branch level and now I just need to allocate the cost to each route. I want the DAX to be dynamic in a way, that it should show me the cost of branch when a branch is selected but also allocate the cost to routes when I want to see the route level.

 

In the example you can see that the Branch has 6 routes, so the Logistics SAP and Sales Force SAP cost should be allocated to each route. Whereas, it is currently showing the total of the branch against each route.

 

This is the DAX that I am using:  

Logistics SAP (Cost per route) = DIVIDE(
-[Logistics Cost (KSA)],
DISTINCTCOUNT(Region_to_Van_mapping[Route]),
0)

zubairs_2-1624465782415.png

 

 

1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

I think you want to multiply the cost by the fraction of routes in the current context over the total number of routes for that branch.

 

This should get you close:

Logistics SAP (Cost per route) =
- [Logistics Cost (KSA)]
    * DIVIDE (
        DISTINCTCOUNT ( Region_to_Van_mapping[Route] ),
        CALCULATE (
            DISTINCTCOUNT ( Region_to_Van_mapping[Route] ),
            REMOVEFILTERS ( Region_to_Van_mapping[Route] )
        ),
        0
    )

 

In your code, DISTINCTCOUNT is just 1 for each of the routes since the route is part of the filter context for those rows (which is why I remove that filter in the denominator for my DAX).

View solution in original post

2 REPLIES 2
zubairs
Helper I
Helper I

@AlexisOlson thank you so much. I had been killing myself over this for the longest time now. You're a Godsent my friend!

AlexisOlson
Super User
Super User

I think you want to multiply the cost by the fraction of routes in the current context over the total number of routes for that branch.

 

This should get you close:

Logistics SAP (Cost per route) =
- [Logistics Cost (KSA)]
    * DIVIDE (
        DISTINCTCOUNT ( Region_to_Van_mapping[Route] ),
        CALCULATE (
            DISTINCTCOUNT ( Region_to_Van_mapping[Route] ),
            REMOVEFILTERS ( Region_to_Van_mapping[Route] )
        ),
        0
    )

 

In your code, DISTINCTCOUNT is just 1 for each of the routes since the route is part of the filter context for those rows (which is why I remove that filter in the denominator for my DAX).

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

Find out what's new and trending in the Fabric community.

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Top Solution Authors