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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

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
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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