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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Anonymous
Not applicable

Subtracting two rows

I am working on a data set, which includes information for about around 30 meters. These meters acted like counters (read data, then add the values on the previous ones meaning all the time increasing - please look at the graphs). I get this information every hour. Then I need to calculate the absolute value for that hour. To reach this goal I need to subtract each row from the previous row. Can I create a general measure and use it for each of 30 columns? Please can you share any example formula in DAX that I can use? What is the best and most efficient way to deal with this? 

01.JPG

1 ACCEPTED SOLUTION

Hello @ehsanbh ,

Sorry to respond late.

For question 1:

If you have about 25-30 similar parameters in this dataset, you might consider creating a measure instead of a calculated column to do this because the computed column will occupy the actual memory. The measure will be as this:

Measure =
VAR a =
    SUM ( 'Table'[Index] ) - 1
VAR previous =
    CALCULATE (
        MAX ( 'Table'[EL,AX12(MWh)] ),
        FILTER ( ALL ( 'Table' ), 'Table'[Index] = a )
    )
RETURN
    IF ( ISBLANK ( previous ), 0, SUM ( 'Table'[EL,AX12(MWh)] ) - previous )

For question 2:

Calculated column:

Column =
VAR _lastrow =
    CALCULATE (
        SUM ( 'Table'[EL,AX12(MWh)] ),
        FILTER ( ALL ( 'Table' ), 'Table'[Index] = EARLIER ( 'Table'[Index] ) - 1 )
    )
RETURN
    IF ( ISBLANK ( _lastrow ), 0, [EL,AX12(MWh)] - _lastrow )

The measure is as above. Here is the result by using the measure:

result.png

Attached a sample file in the next one, hopes to help you.

Best Looks,
Yingjie Li

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

View solution in original post

4 REPLIES 4
Syndicate_Admin
Administrator
Administrator

Thank you very much, very good code. It is much appreciated.

amitchandak
Super User
Super User

@Anonymous , The information you have provided is not making the problem clear to me. Can you please explain with an example.

 

There is nothing like the previous row in Power BI. Now if you meter /step /year/week no. Or any incremental no or rank you can use rank or number for the previous row. The condition is that you have to move that to a new table and use that to build current previous

 

example in the case of week(Step/meter). A new column in week/date table

new column

Week Rank = RANKX(all('Date'),'Date'[Week Start date],,ASC,Dense)

 

new measures
This Week = CALCULATE(sum('order'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])))
Last Week = CALCULATE(sum('order'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])-1))


Appreciate your Kudos.


Anonymous
Not applicable

@amitchandak

Sorry to be confusing! Here is one example. I guess I have solved it half a way! I have EL, AX12 (MWh), which is electricity meter values (adding on previous value on hourly base) and I need a new column for absolute consumption for each specific hour. In this case I need to subtract the value of each row from the previous one.

I have used below DAX formula for a new calculated column and actually it works to some extent:

EL, AX12, abs

raw_measurement[EL, AX12 (MWh)]

- CALCULATE (

SUM ( raw_measurement[EL, AX12 (MWh)] ),

FILTER ( raw_measurement, raw_measurement[Index] = EARLIER ( raw_measurement[Index] ) - 1 )

)

02.JPG

Two questions:

1- I have around 25-30 similar parameters in this data set. Is this the way to go forward? I mean creating a calculated column for each parameter? Or is there a more efficient way to perform this?

2- As you see the first value has not been changed. How can I change the code to have zero for the first value?

Hello @ehsanbh ,

Sorry to respond late.

For question 1:

If you have about 25-30 similar parameters in this dataset, you might consider creating a measure instead of a calculated column to do this because the computed column will occupy the actual memory. The measure will be as this:

Measure =
VAR a =
    SUM ( 'Table'[Index] ) - 1
VAR previous =
    CALCULATE (
        MAX ( 'Table'[EL,AX12(MWh)] ),
        FILTER ( ALL ( 'Table' ), 'Table'[Index] = a )
    )
RETURN
    IF ( ISBLANK ( previous ), 0, SUM ( 'Table'[EL,AX12(MWh)] ) - previous )

For question 2:

Calculated column:

Column =
VAR _lastrow =
    CALCULATE (
        SUM ( 'Table'[EL,AX12(MWh)] ),
        FILTER ( ALL ( 'Table' ), 'Table'[Index] = EARLIER ( 'Table'[Index] ) - 1 )
    )
RETURN
    IF ( ISBLANK ( _lastrow ), 0, [EL,AX12(MWh)] - _lastrow )

The measure is as above. Here is the result by using the measure:

result.png

Attached a sample file in the next one, hopes to help you.

Best Looks,
Yingjie Li

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

Helpful resources

Announcements
March Fabric Community Update

Fabric Community Update - March 2024

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

Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.