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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
NBOnecall
Helper V
Helper V

Calculating Cost Per Unit based off of a total cost

Hi, 

 

I am needing help wrapping my head around the best way to apply a percentage based off of the total volume per item of a shipment. 

 

Here is the data I am working with. On this shipment we have 6 different products being shipped and a total of 87 units. The total cost of that Shipment was $167. I would like an output like the one attached at the bottom. 

 

Thank you.

 

DIMS and QTY.pngShipment with cost.pngOutput.png

1 ACCEPTED SOLUTION
jdbuchanan71
Super User
Super User

Hello @NBOnecall 

A couple measures to get you to your goal.

Total Volume uses SUMX to calc qty * volume

Total Volume = SUMX ( shipments, shipments[Qty] * shipments[Volume] )

Quantity is just a straight sum

SumQty = Sum(shipments[Qty])

Total cost is done with a cross filter so the shipment id can flow back up the relationship to the cost table.

SumCost = 
CALCULATE (
    SUM ( Cost[Cost] ),
    CROSSFILTER ( Cost[ShipmentID], shipments[ShipmentID], BOTH )
)

Then the mesure to allocate the cost per shipment across the lines using our [Total Volume] measure

Total Cost = 
VAR Shipment =
    SELECTEDVALUE ( shipments[ShipmentID] )
VAR TotalShipmentVolume =
    CALCULATE (
        [Total Volume],
        ALL ( shipments ),
        shipments[ShipmentID] = Shipment
    )
VAR LineVolume = [Total Volume]
VAR LinePortion =
    DIVIDE ( LineVolume, TotalShipmentVolume )
RETURN
    IF ( HASONEVALUE ( shipments[ShipmentID] ), LinePortion * [SumCost], [SumCost] )

It includes the IF ( HASONEVALE () ) portion so that subtotals on the measure will work correctly.

 

Finally the per unit cost measure.

Cost Per Item = DIVIDE( [Total Cost] , [SumQty] )

LineCost.png

View solution in original post

3 REPLIES 3
jdbuchanan71
Super User
Super User

Hello @NBOnecall 

A couple measures to get you to your goal.

Total Volume uses SUMX to calc qty * volume

Total Volume = SUMX ( shipments, shipments[Qty] * shipments[Volume] )

Quantity is just a straight sum

SumQty = Sum(shipments[Qty])

Total cost is done with a cross filter so the shipment id can flow back up the relationship to the cost table.

SumCost = 
CALCULATE (
    SUM ( Cost[Cost] ),
    CROSSFILTER ( Cost[ShipmentID], shipments[ShipmentID], BOTH )
)

Then the mesure to allocate the cost per shipment across the lines using our [Total Volume] measure

Total Cost = 
VAR Shipment =
    SELECTEDVALUE ( shipments[ShipmentID] )
VAR TotalShipmentVolume =
    CALCULATE (
        [Total Volume],
        ALL ( shipments ),
        shipments[ShipmentID] = Shipment
    )
VAR LineVolume = [Total Volume]
VAR LinePortion =
    DIVIDE ( LineVolume, TotalShipmentVolume )
RETURN
    IF ( HASONEVALUE ( shipments[ShipmentID] ), LinePortion * [SumCost], [SumCost] )

It includes the IF ( HASONEVALE () ) portion so that subtotals on the measure will work correctly.

 

Finally the per unit cost measure.

Cost Per Item = DIVIDE( [Total Cost] , [SumQty] )

LineCost.png

Thank you for replying. I well definelty try your way, but as I was waiting for a reply I went through and worked it a different way that I think gets the same results, but generally tried to based it off of sumif formula of Excel. 

 

For shipment Cost I added a column to my shipment report - 

 

Shipment Cost = CALCULATE(sum('Random Shipment Data Cost'[Cost]),filter('Random Shipment Data Cost','Random Shipment Data Cost'[ShipmentId] = 'hup ShipmentItem'[ShipmentId]))
 
Then for the volumn of the item I pulled I used lookupvalue to get the volume calculated from another table onto my shipment table
 
I then calculcated the total vloume as 
= 'hup ShipmentItem'[Volume]*'hup ShipmentItem'[QtyReceived]
 
After some research I was able to find total volume of shipment by using a Calculate, filter formula.
 
Total Volume for Shipment = CALCULATE(sum('hup ShipmentItem'[Total Volume]),filter('hup ShipmentItem','hup ShipmentItem'[ShipmentId]= Earlier ('hup ShipmentItem'[ShipmentId])))
 
And then total Cost and Total Cost per unit was a simple multiply and divide formula. 
 
My output looked like this - Finished.png
 
Now my question to @jdbuchanan71, what way is better and for what reason. I am still pretty new to PowerBI so anything helps. 
 
Thanks!

Hello @NBOnecall 

For me the "better" way is the one that works that I understand.  Sometimes the layers of formulas can get confusing and I want to be able to predict the behavior of the measures.

 

If both of the methods perform equally well (calculate quickly in visuals) then I would use the one you came up with on your own.

 

Cheers!

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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