cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
bigrods
Frequent Visitor

Subtract previous Column total from current row per ID

Hi everyone, I have searched for an answer to this, but have got stuck in a muddle with DAX so hoping someone could please put me out of my misery!

 

I have a dataset where I need to calculate the progress of students from lesson 1 to lesson 2.

 

Student is scored at Lesson 1 then scored again at Lesson 2.

I need to subtract the lesson 1 score from the lesson 2 score to get the Progress value for each Student ID.

Not all students will have a lesson 2 entry (as their lesson 2 may not have taken place yet) - the Progress should only be calculated at Lesson 2.

 

I was trying to do this under a calculated column, but not sure if a measure would be better? An example of my data is below, I have created a student_lesson column which is the Student ID and Lesson ID concatenated then made an index column based on this, as assessments could be entered in any order so didn't want to make an index based on this.

The Progress column is what I want it to look like (unless a measure is better?)

 

Assessment IDStudent IDLesson NoScoreStudent_lessonIndexProgress
11120111 
351210012280
42130213 
23229022460
653140315 
64110416 
84210042790

 

I have entered (the latest version of!) my code but have tried all sorts including using the EARLIER function but just can't get the syntax right.

 

Progress = 
var index = tbl_Assessment[index]
var students = tbl_Assessment[Student_ID]
var prevrow =
CALCULATE(
    SUMX(tbl_Assessment,tbl_Assessment[Score](
    FILTER(tbl_Assessment,
    tbl_Assessment[index]<index && tbl_Assessment[Student_ID] = students))))
return
CALCULATE(SUMx(tbl_Assessment,tbl_Assessment[Score]),FILTER(tbl_Assessment,tbl_Assessment[Lesson_No]=2)-prevrow)

 

 Many thanks for any help!

1 ACCEPTED SOLUTION
v-stephen-msft
Community Support
Community Support

Hi @bigrods ,

 

Try this calculated column

Process =
IF (
    [Lesson No] = 2,
    CALCULATE (
        SUM ( tbl_Assessment[Score] ),
        FILTER (
            ALLEXCEPT ( 'tbl_Assessment', tbl_Assessment[Student ID] ),
            [Lesson No] = 2
        )
    )
        - CALCULATE (
            SUM ( tbl_Assessment[Score] ),
            FILTER (
                ALLEXCEPT ( 'tbl_Assessment', tbl_Assessment[Student ID] ),
                [Lesson No] = 1
            )
        )
)

1.png

 

You can check more details from here.

 

 

 

Best Regards,

Stephen Tao

 

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

7 REPLIES 7
v-stephen-msft
Community Support
Community Support

Hi @bigrods ,

 

Try this calculated column

Process =
IF (
    [Lesson No] = 2,
    CALCULATE (
        SUM ( tbl_Assessment[Score] ),
        FILTER (
            ALLEXCEPT ( 'tbl_Assessment', tbl_Assessment[Student ID] ),
            [Lesson No] = 2
        )
    )
        - CALCULATE (
            SUM ( tbl_Assessment[Score] ),
            FILTER (
                ALLEXCEPT ( 'tbl_Assessment', tbl_Assessment[Student ID] ),
                [Lesson No] = 1
            )
        )
)

1.png

 

You can check more details from here.

 

 

 

Best Regards,

Stephen Tao

 

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

Great, thanks so much - this has done the trick - and thanks to @Mikelytics and @sanalytics for their assistance too.

sanalytics
Responsive Resident
Responsive Resident

@bigrods 

 

You can follow the below pattern also

 

sanalytics_0-1611500205703.png

 

Attached link is the pbix file

https://dropfiles.org/WhgoHdhk

 

Regards

sanalytics

if it is your solution then please like and accept it as your solution

Hi @sanalytics 

 

Thanks for the reply, I am a couple of versions of PBI behind, need to get my IT to upgrade my version next week so unfortunately cannot view your pbix file.

When I run your code, every value in the Progress column is blank - I have searched the code but cannot see anything glaring, it all looks fine. All columns are Whole Number format, would you have any possible suggestions? thanks a lot!

Mikelytics
Resolver III
Resolver III

Hi @bigrods ,

 

I think it would make sense to solve this using measures

 

one measure for lesson one, one for lesson 2 and one for the delta. To also calulcate the average and single progres I would use the average function.

 

e.g.

Lesson 1 Score = CALCUATE(AVERAGE(table[lesson score]),table[lesson score]=1)

 

Lesson 2 Score = CALCUATE(AVERAGE(table[lesson score]),table[lesson score]=2)

 

Progress = [lesson 2 score] - [lesson 1 score]

 

THe create a table (or matrix) with the students as row and the three measures as values.

 

I hope that helps.

 

Best regards

Mikelytics

 

Did I solve your request? Please mark my post as solution.

 

Appreciate your Kudos.

 

Hi @Mikelytics 

 

Thanks so much, that works to get them into a matrix (see below).

 

Is it possible to put the measure into a chart, i.e a bar chart showing the no. of students at each progress point (10,20,30 etc?) I have tried (below) but it's rightly not splitting into seperate points. Apologies, I should have figured that out before. Is this where the calculated column comes in?

 

bigrods_0-1611499888078.png

Many thanks

Hi @bigrods ,

 

you are right in this case you need a calculated column.

 

Please try the following calculated column:

 

CALCULATE(Max(table[score]),

Filter(ALL(table),

table[student ID] = EARLIER(table[student ID]) && table[lesson ID] = 2))


Best regards

Mikelytics

 

 

 

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group

April Update

Check it Out!

Click here to read more about the April 2021 Updates!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.

secondImage

Experience what’s next for Power BI

See the latest Power BI innovations, updates, and demos from the Microsoft Business Applications Launch Event.