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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
Valentin09
Regular Visitor

Subtract two values based on Rank

I have the following table:

 

Valentin09_0-1734359705942.png

I want to subtract the current testscore (Testrang = 1) with the previous testscore (Testrang = 2). In this example I want to have the following calculation: Name: "Aaron" / current score = 50 / previous testscore = 50 --> result: 0

 

Either as a measure or as a new column.

 

I hope somebody can help me.

 

Best regards,

Valentin

1 ACCEPTED SOLUTION
mark_endicott
Super User
Super User

Ok so in that case the visual must already have been filtered to the test type. If you have multiple tests per person, within the same type, how are you filtering it to show the 2 most recent results? If you are not filtering it, and you are using measures to display columns 2 & 3 of your visual, you'll need to factor this into the DAX, I suggest something like this:

 

VAR _name =
    SELECTEDVALUE ( 'Table'[Name] )
VAR _test_type = 
    SELECTEDVALUE( 'Table'[Test] )
VAR _recent_test = 
    MAX ( 'Table'[Testrang] )
VAR _recent_test_score = 
    CALCULATE (
        SUM ( 'Table'[Wert] ),
        REMOVEFILTERS ( 'Table'[Testrang] ),
        'Table'[Testrang] = _recent_test
            && 'Table'[Name] = _name
            && 'Table'[Test] = _test_type
    )
VAR _prev_test = _recent_test - 1
VAR _prev_test_score =
    CALCULATE (
        SUM ( 'Table'[Wert] ),
        REMOVEFILTERS ( 'Table'[Testrang] ),
        'Table'[Testrang] = _prev_test
            && 'Table'[Name] = _name
            && 'Table'[Test] = _test_type
    )
VAR _current_minus_prev =
    _recent_test_score - _prev_test_score
RETURN
    _current_minus_prev

 

If this works for you please accept as the solution for visibilty of others. 

View solution in original post

8 REPLIES 8
Anonymous
Not applicable

Thanks for the replies from mark_endicott.

 

Hi @Valentin09 ,

 

Based on your description, I created simple data:

vlinhuizhmsft_0-1734404203576.png

 

Please try the following DAX formula:

 

 

Difference = 
VAR _count=CALCULATE(COUNT('Table'[Name]),ALLEXCEPT('Table','Table'[Name]))
VAR _current=MAX('Table'[Testrang])
VAR CurrentTestrang=CALCULATE(SUM('Table'[Wert]),FILTER(ALLEXCEPT('Table','Table'[Name]),'Table'[Testrang]=_current))
VAR PreviousTestrang=CALCULATE(SUM('Table'[Wert]),FILTER(ALLEXCEPT('Table','Table'[Name]),'Table'[Testrang]=_current-1))
return
IF(_count>1&&_current>1,CurrentTestrang-PreviousTestrang,blank())

 

 

 

Result:

vlinhuizhmsft_3-1734405065779.png

 

Best Regards,
Zhu

 

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

mark_endicott
Super User
Super User

Ok so in that case the visual must already have been filtered to the test type. If you have multiple tests per person, within the same type, how are you filtering it to show the 2 most recent results? If you are not filtering it, and you are using measures to display columns 2 & 3 of your visual, you'll need to factor this into the DAX, I suggest something like this:

 

VAR _name =
    SELECTEDVALUE ( 'Table'[Name] )
VAR _test_type = 
    SELECTEDVALUE( 'Table'[Test] )
VAR _recent_test = 
    MAX ( 'Table'[Testrang] )
VAR _recent_test_score = 
    CALCULATE (
        SUM ( 'Table'[Wert] ),
        REMOVEFILTERS ( 'Table'[Testrang] ),
        'Table'[Testrang] = _recent_test
            && 'Table'[Name] = _name
            && 'Table'[Test] = _test_type
    )
VAR _prev_test = _recent_test - 1
VAR _prev_test_score =
    CALCULATE (
        SUM ( 'Table'[Wert] ),
        REMOVEFILTERS ( 'Table'[Testrang] ),
        'Table'[Testrang] = _prev_test
            && 'Table'[Name] = _name
            && 'Table'[Test] = _test_type
    )
VAR _current_minus_prev =
    _recent_test_score - _prev_test_score
RETURN
    _current_minus_prev

 

If this works for you please accept as the solution for visibilty of others. 

This works perfectly! I just had to change -1 to +1, because most recent test has the 1, the penultimate the 2 and so on.

@Valentin09 - No problem, I missed it saying the current test was 1 in your original description. 

 

I'm glad you've been able to amend my DAX accordingly. 

Valentin09
Regular Visitor

Thanks a lot for your response, but unfortunately it isn't working as I wished. Here is the formula I have used:

Valentin09_0-1734362716895.png

 

And here is the visual with the scores:

Valentin09_1-1734362850929.png

 

What am I doing wrong?

@Valentin09  - Do you have multiple test types? This was't specified, so it looks like my measure is returning the first result it finds, regardless of test type.

 

In which case use this:

 

VAR _name =
    SELECTEDVALUE ( 'Table'[Name] )
VAR _test_type = 
    SELECTEDVALUE( 'Table'[Test] )
VAR _prev_test =
    SELECTEDVALUE ( 'Table'[Testrang] ) - 1
VAR _prev_test_score =
    CALCULATE (
        SUM ( 'Table'[Wert] ),
        REMOVEFILTERS ( 'Table'[Testrang] ),
        'Table'[Testrang] = _prev_test
            && 'Table'[Name] = _name
            && 'Table'[Test] = _test_type
    )
VAR _current_minus_prev =
    SUM ( 'Table'[Wert] ) - _prev_test_score
RETURN
    _current_minus_prev

 

If this works for you please accept as the solution for visibilty of others. 

Thanks a lot, but this has no effect on the values. Yes I have different Testtypes. 

mark_endicott
Super User
Super User

@Valentin09 - See below:

 

VAR _name =
    SELECTEDVALUE ( 'Table'[Name] )
VAR _prev_test =
    SELECTEDVALUE ( 'Table'[Testrang] ) - 1
VAR _prev_test_score =
    CALCULATE (
        SUM ( 'Table'[Wert] ),
        REMOVEFILTERS ( 'Table'[Testrang] ),
        'Table'[Testrang] = _prev_test
            && 'Table'[Name] = _name
    )
VAR _current_minus_prev =
    SUM ( 'Table'[Wert] ) - _prev_test_score
RETURN
    _current_minus_prev

You'll just need to swap out my table and column names for yours. 

 

If this works for you please accept as the solution for visibilty of others. 

 

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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