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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
rahulgade
Frequent Visitor

Create a new column based on matching condition

Hello All

I am trying to add a new column as " Previous Year Score" which will give me a score before two years for an indivudual school.

 

e.g  school "A" in 2019 scored "222" for English

I want to create a new column which shows  School "A" in 2017 scored 214 in English   

All the values are in the same table. 

rahulgade_0-1602469905568.png

 many thanks

 

 

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @rahulgade ,

 

Try this:

Column = 
CALCULATE (
    SUM ( 'Gain Table (2)'[Mean] ),
    FILTER (
        'Gain Table (2)',
        'Gain Table (2)'[School Name] = EARLIER ( 'Gain Table (2)'[School Name] )
            && 'Gain Table (2)'[Assessment Area]
                = EARLIER ( 'Gain Table (2)'[Assessment Area] )
            && 'Gain Table (2)'[Calendar Year]
                = EARLIER ( 'Gain Table (2)'[Calendar Year] ) - 2
    )
)

 

 

 

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

7 REPLIES 7
Jimmy801
Community Champion
Community Champion

Hello @rahulgade 

 

you can use a formula like this

 

        (row)=> try Table.SelectRows(ChangeType, each [School name]=row[School name] and [Year]=row[Year]-2 and [Assessment name]= row[Assessment name])[Score]{0} otherwise null

 

 

Here the complete code

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTIyMLQEUql5QMJQKVYnWskJIZpWBGKDRZ3RRI3Boi4I0dxEIGECFoWaaw4z1xTZXLioGbK5cFFzZHPhohZKsbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"School name" = _t, Year = _t, #"Assessment name" = _t, Score = _t]),
    ChangeType = Table.TransformColumnTypes(Source,{{"School name", type text}, {"Year", Int64.Type}, {"Score", Int64.Type}}),
    AddScoreBefore2Years = Table.AddColumn
    (
        ChangeType,
        "Previous2YearScore",
        (row)=> try Table.SelectRows(ChangeType, each [School name]=row[School name] and [Year]=row[Year]-2 and [Assessment name]= row[Assessment name])[Score]{0} otherwise null
    )
in
    AddScoreBefore2Years

 

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

AlB
Community Champion
Community Champion

Hi @rahulgade 

This is simpler in DAX.  A new calculated column:

New col =
VAR previousYear_ =
    CALCULATE (
        MAX ( Table1[Year] ),
        Table1[Year] < EARLIER ( Table1[Year] ),
        ALLEXCEPT ( Table1, Table1[School name] ),
        Table1[Assesment name]
    )
RETURN
    CALCULATE (
        DISTINCT ( Table1[Score] ),
        Table1[Year] = previousYear_,
        ALLEXCEPT ( Table1, Table1[School name] ),
        Table1[Assesment name]
    )

 

Please mark the question solved when done and consider giving kudos if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

 

SU18_powerbi_badge

rahulgade
Frequent Visitor

Hello AIB

thank you for your reply, i am getting an error in my "assessment area" 

Cannot convert value 'English' of type Text to type true/false. 

AlB
Community Champion
Community Champion

@rahulgade 

There was a mistake while copying the code

ew col =
VAR previousYear_ =
    CALCULATE (
        MAX ( Table1[Year] ),
        Table1[Year] < EARLIER ( Table1[Year] ),
        ALLEXCEPT ( Table1, Table1[School name], Table1[Assesment name] )
    )
RETURN
    CALCULATE (
        DISTINCT ( Table1[Score] ),
        Table1[Year] = previousYear_,
        ALLEXCEPT ( Table1, Table1[School name], Table1[Assesment name] )
    )

Please mark the question solved when done and consider giving kudos if posts are helpful.

 

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

 

Cheers 

 

SU18_powerbi_badge

rahulgade
Frequent Visitor

Hello Again @AlB , 

 

actual code i am using as per your instruction is , 

New col =
VAR previousYear_ =
CALCULATE (
MAX ( 'Gain Table (2)'[Year Level] ),
'Gain Table (2)'[Year Level] < EARLIER ( 'Gain Table (2)'[Year Level] ),
ALLEXCEPT ( 'Gain Table (2)','Gain Table (2)'[School Name],'Gain Table (2)'[Assessment Area] )
)
RETURN
CALCULATE (
DISTINCT ( 'Gain Table (2)'[Mean] ),
'Gain Table (2)'[Year Level] = previousYear_,
ALLEXCEPT ( 'Gain Table (2)', 'Gain Table (2)'[School Name], 'Gain Table (2)'[Assessment Area])
)
 
 
now the error i am getting " A table of multiple values was supplied where a single value was expected."
 
thanks 
 
Icey
Community Support
Community Support

Hi @rahulgade ,

 

Try this:

Column = 
CALCULATE (
    SUM ( 'Gain Table (2)'[Mean] ),
    FILTER (
        'Gain Table (2)',
        'Gain Table (2)'[School Name] = EARLIER ( 'Gain Table (2)'[School Name] )
            && 'Gain Table (2)'[Assessment Area]
                = EARLIER ( 'Gain Table (2)'[Assessment Area] )
            && 'Gain Table (2)'[Calendar Year]
                = EARLIER ( 'Gain Table (2)'[Calendar Year] ) - 2
    )
)

 

 

 

Best Regards,

Icey

 

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

Thank you very much, Icey

That was exactly what I wanted to achieve. 

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

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

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

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.

Top Solution Authors