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
sp_mike
Helper II
Helper II

Calculating difference between two values per category

I have this issue.

One (groupBy table):

 

week   costs   orderID

1           10        001

1           12        002

2           15        001

2           18        002

 

One order table:

 

orderID    supplier region

001           john         5

002           sarah        6

 

As a result I want some visual like this (costs per supplier per week):

 

Week        1         2        3

-----------------------------

sarah        12       18

john         10        15

 

Diff           2          3

 

 

The key question is, I think, how can I create a measure or column that does this Diff caluculation.

 

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @sp_mike ,

You can create your measure like so:

Costs Measure =
VAR Order_ID =
    MAX ( 'order table'[orderID] )
RETURN
    IF (
        HASONEVALUE ( 'order table'[supplier] ),
        MAX ( 'groupBy table'[costs] ),
        MAX ( 'groupBy table'[costs] )
            - CALCULATE (
                MAX ( 'groupBy table'[costs] ),
                'order table'[orderID] = Order_ID - 1
            )
    )

diff.PNG

 

And if you have more than 2 suppliers, you can ceate measures like so:

Diff =
VAR Order_ID =
    MAX ( 'groupBy table'[orderID] ) - 1
VAR Previous_Costs =
    CALCULATE (
        MAX ( 'groupBy table'[costs] ),
        FILTER (
            ALLEXCEPT ( 'groupBy table', 'groupBy table'[week] ),
            'groupBy table'[orderID] = Order_ID
        )
    )
RETURN
    MAX ( 'groupBy table'[costs] ) - Previous_Costs

diff2.PNG

diff3.jpg

PBIX file attached.

 

Best Regards,
Icey

 

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

2 REPLIES 2
Ashish_Mathur
Super User
Super User

Hi,

How will you calculate the difference row if there are more than 2 suppliers?


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Icey
Community Support
Community Support

Hi @sp_mike ,

You can create your measure like so:

Costs Measure =
VAR Order_ID =
    MAX ( 'order table'[orderID] )
RETURN
    IF (
        HASONEVALUE ( 'order table'[supplier] ),
        MAX ( 'groupBy table'[costs] ),
        MAX ( 'groupBy table'[costs] )
            - CALCULATE (
                MAX ( 'groupBy table'[costs] ),
                'order table'[orderID] = Order_ID - 1
            )
    )

diff.PNG

 

And if you have more than 2 suppliers, you can ceate measures like so:

Diff =
VAR Order_ID =
    MAX ( 'groupBy table'[orderID] ) - 1
VAR Previous_Costs =
    CALCULATE (
        MAX ( 'groupBy table'[costs] ),
        FILTER (
            ALLEXCEPT ( 'groupBy table', 'groupBy table'[week] ),
            'groupBy table'[orderID] = Order_ID
        )
    )
RETURN
    MAX ( 'groupBy table'[costs] ) - Previous_Costs

diff2.PNG

diff3.jpg

PBIX file attached.

 

Best Regards,
Icey

 

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

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.