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
MaighreadL
New Member

Calaculate the difference between one column if the other column contains a certain text

Hi There. 

I was hoping you could help me with this. 

I have a table where I would like the difference to be calculated based on the item number 

MaighreadL_0-1594045625230.png

So for example Item Number 22 I'd like the difference of landed unit cost between the current item number 22 and the previous one sold to return into another column 

 

I have created a calculated column with this formula

 

 

 

 

 

 

 

CalculatedDifference =
VAR PreviousItemNumber_ =
CALCULATE (
MAX ( Sheet1[Item Number] ),
Sheet1[Item Number] < EARLIER (Sheet1[Item Number]),
ALLEXCEPT ( Sheet1, Sheet1[Item Number] )
)
VAR PreviousLandedCost_ =
CALCULATE (
DISTINCT ( Sheet1[Landed Unit Cost] ),
Sheet1[Item Number] = PreviousItemNumber_,
ALLEXCEPT ( Sheet1, Sheet1[Item Number] )
)
VAR CurrentLandedCost_ = Sheet1[Landed Unit Cost]
RETURN
IF (
NOT ISBLANK ( CurrentLandedCost_ ) && NOT ISBLANK ( PreviousLandedCost_ ),
CurrentLandedCost_ - PreviousLandedCost_

 

 

 

 

 

 

 

But it is returning an error ;A table of multiple values was supplied where a single value was expected

Here is a copy of the table

 

DatePO NumberItem NumberLanded Unit Cost

Wednesday 1 January 202012210
Thursday 2 January 202022212
Friday 3 January 20203112.86
Saturday 4 January 20204112.85
Sunday 5 January 20205112.84
Monday 6 January 20206773.84
Tuesday 7 January 20207773.89
Wednesday 8 January 20208773.89
Thursday 9 January 20209773.82
Friday 10 January 202010773.75
Saturday 11 January 202011773.75
Sunday 12 January 202012773.75
Monday 13 January 202013221.2
Tuesday 14 January 202014221.2
Wednesday 15 January 202015335
Thursday 16 January 202016335.14
Friday 17 January 202017335.12
Saturday 18 January 202018335.12

 

 

Thank you ! 

1 ACCEPTED SOLUTION
harshnathani
Community Champion
Community Champion

HI @MaighreadL ,

 

 

Create a Calculated Column

 

 

Difference =
VAR a =
    CALCULATE (
        MAX ( 'Table'[Date] ),
        FILTER (
            'Table',
            'Table'[Item Number]
                = EARLIER ( 'Table'[Item Number] )
                && 'Table'[Date]
                    < EARLIER ( 'Table'[Date] )
        )
    )
VAR b =
    CALCULATE (
        MAX ( 'Table'[Unit Cost] ),
        FILTER (
            'Table',
            'Table'[Item Number]
                = EARLIER ( 'Table'[Item Number] )
                && 'Table'[Date] = a
        )
    )
RETURN
    IF (
        b
            <> BLANK (),
        'Table'[Unit Cost] - b
    )

 

 

1.jpg

 

 

Regards,

Harsh Nathani

Appreciate with a Kudos!! (Click the Thumbs Up Button)

Did I answer your question? Mark my post as a solution!

View solution in original post

3 REPLIES 3
harshnathani
Community Champion
Community Champion

HI @MaighreadL ,

 

 

Create a Calculated Column

 

 

Difference =
VAR a =
    CALCULATE (
        MAX ( 'Table'[Date] ),
        FILTER (
            'Table',
            'Table'[Item Number]
                = EARLIER ( 'Table'[Item Number] )
                && 'Table'[Date]
                    < EARLIER ( 'Table'[Date] )
        )
    )
VAR b =
    CALCULATE (
        MAX ( 'Table'[Unit Cost] ),
        FILTER (
            'Table',
            'Table'[Item Number]
                = EARLIER ( 'Table'[Item Number] )
                && 'Table'[Date] = a
        )
    )
RETURN
    IF (
        b
            <> BLANK (),
        'Table'[Unit Cost] - b
    )

 

 

1.jpg

 

 

Regards,

Harsh Nathani

Appreciate with a Kudos!! (Click the Thumbs Up Button)

Did I answer your question? Mark my post as a solution!

@MaighreadL I'm sure @harshnathani solution will work, I didn't look at it but it can have performance implications on a large dataset. I would add a measure using the following DAX expression:

 

Measure = 
VAR __tbl = ALL ( 'Table'[Id], 'Table'[DatePO] )
VAR __prevDate = CALCULATE ( MAX ( 'Table'[DatePO] ), FILTER ( __tbl, 'Table'[DatePO] < MAX ( 'Table'[DatePO] ) ) )
RETURN 
CALCULATE ( SUM ( 'Table'[Amount] ), __tbl, 'Table'[DatePO] = __prevDate)

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

@harshnathani  This is perfect !!! Thank you so much !!!

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.