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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Nathan_O
Frequent Visitor

DAX Formula for an Item's change from Prior Unit Cost

My goal is to get a waterfall graph, showing items' change in cost across time.

 

I have a table akin to this:

Shipment Data

ItemShip DateExtended CostQuantityUnit Cost
Item A1/1/20205001500
Item A1/1/202011002550
Item A1/2/202012002600
Item A1/15/20205101510
Item B1/10/2020200021000
Item B1/12/2020120011200

 

 

 

The issue I'm running into is the PreviousDateWithCost component is finding the last date with any cost, rather than taking into account the item-level filtering at the visualization level.

 

 

Cost Delta = 
    VAR PreviousDateWithCost = 
        CALCULATE (
            MAX( [Ship Date] ),
            FILTER ( ALL ( 'Shipment Data' ),[Extended Cost] > 0 && [Quantity] > 0 && [Ship Date] < MAX ( [Ship Date] ) && [Item] = [Item])
        )
    VAR PreviousCost =
        CALCULATE (
            DIVIDE( SUM ( [Extended Cost] ) , SUM ( [Quantity] ) ),
            FILTER ( ALL ( 'Shipment Data' ), [Ship Date] = PreviousDateWithCost && [Item] = [Item])
        )
RETURN
    [Unit Cost] / PreviousCost

 

1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @Nathan_O ,

If you want to get each item's max date to calculate, try to modify the formula like this:

 

Cost Delta = 
VAR _previousdate =
    CALCULATE (
        MAX ( [Ship Date] ),
        FILTER (
            ALLEXCEPT ( 'Shipment Data', 'Shipment Data'[Item] ),
            [Extend Cost] > 0
                && [Quantity] > 0
        )
    )
VAR _previouscost =
    CALCULATE (
        DIVIDE ( SUM ( [Extend Cost] ), SUM ( [Quantity] ), BLANK () ),
        FILTER (
            ALLEXCEPT ( 'Shipment Data', 'Shipment Data'[Item] ),
            [Ship Date] = _previousdate
        )
    )
RETURN
    [Unit Cost] / _previouscost

 

Cost Delta.png

 

Best Regards,
Yingjie 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
v-yingjl
Community Support
Community Support

Hi @Nathan_O ,

If you want to get each item's max date to calculate, try to modify the formula like this:

 

Cost Delta = 
VAR _previousdate =
    CALCULATE (
        MAX ( [Ship Date] ),
        FILTER (
            ALLEXCEPT ( 'Shipment Data', 'Shipment Data'[Item] ),
            [Extend Cost] > 0
                && [Quantity] > 0
        )
    )
VAR _previouscost =
    CALCULATE (
        DIVIDE ( SUM ( [Extend Cost] ), SUM ( [Quantity] ), BLANK () ),
        FILTER (
            ALLEXCEPT ( 'Shipment Data', 'Shipment Data'[Item] ),
            [Ship Date] = _previousdate
        )
    )
RETURN
    [Unit Cost] / _previouscost

 

Cost Delta.png

 

Best Regards,
Yingjie Li

If this post helps then please consider Accept it as the solution to help the other members find it more quickly.

Hi @v-yingjl and @edhans, thanks for the help!

I tried implementing v-yingjl's code, and that got me most of the way there, but I ran into a snag; the measure is pulling the most recent ship date, instead of the prior date before the measure's context.

 

I've duplicated the _previousdate into _currentdate and added [Ship Date] to the ALLEXCEPT formula to return the row's ship date. Then in _previousdate, added a filter for [Ship Date] < _currentdate and that solved the issue.

Lastly, the earliest dates in the table were returning _previousdate = 0 and _previouscost = 0. So I added an intermediary variable to replace _previousdate = 0 with _currentdate.

 

 

Cost Delta = 
    VAR _currentdate = 
        CALCULATE (
            MAX( [Ship Date] ),
            FILTER (
                ALLEXCEPT(  'Shipment Data' , 'Shipment Data'[Item] , 'Shipment Data'[Ship Date] ),
                    [Extended Cost] > 0 
                        && [Quantity] > 0
            )
        )

    VAR _previousdate = 
        CALCULATE (
            MAX( [Ship Date] ),
            FILTER (
                ALLEXCEPT(  'Shipment Data' , 'Shipment Data'[Item] ),
                    [Extended Cost] > 0 
                        && [Quantity] > 0
                        && [Ship Date] < _currentdate
            )
        )

    VAR _effectivepreviousdate = 
        IF(_previousdate = 0,_currentdate,_previousdate)

    VAR _previouscost =
        CALCULATE (
            DIVIDE( SUM ( [Extended Cost] ) , SUM ( [Quantity] ) , 0 ),
            FILTER (
                 ALLEXCEPT( 'Shipment Data' , 'Shipment Data'[Item] ),
                 [Ship Date] = _effectivepreviousdate
            )
        )
RETURN
    [Unit Cost] / _previouscost

 

 

 

ItemShip DateExtended CostQuantityUnit CostGoal Datev-yingjl's _previousdate_currentdate
_previousdate
_effectivepreviousdate
Item A1/1/202050015001/1/20201/15/20201/1/202001/1/2020
Item A1/1/2020110025501/1/20201/15/20201/1/202001/1/2020
Item A1/2/2020120026001/1/20201/15/20201/2/20201/1/20201/1/2020
Item A1/15/202051015101/2/20201/15/20201/15/20201/2/20201/2/2020
Item B1/10/20202000210001/10/20201/12/20201/10/202001/10/2020
Item B1/12/20201200112001/10/20201/12/20201/12/20201/10/20201/10/2020

 

There is probably a more elegant way of doing this, but the code above accomplishes the goal! Thank you guys so much for the help! Any cleanup tips would be greatly appreciated.

edhans
Super User
Super User

This measure will do that.

Max Date = 
VAR LastDateWithAnyCost =
    MAXX(
        FILTER(
            ALL( 'Table' ),
            'Table'[Unit Cost] <> 0
        ),
        'Table'[Ship Date]
    )
RETURN
    LastDateWithAnyCost

 

It returns the below data.

2020-05-21 14_18_46-Untitled - Power BI Desktop.png

Your measure above is calling a lot of other measures, and one is [item] = [item] which doesn't make much since since 1 = 1, and all of those measures are getting some context transition because the whole thing is wrapped in CALCULATE and measures get an implicit CALCULATE() when reused, so the amount of filtering going on there is a lot, and may be difficult to track down. I'd componentize the whole thing and not call a lot of other measures if possible, and ditch CALCULATE() if possible.



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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