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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
roosechua
Frequent Visitor

Adding new column by summing a filtered column from another table

Hello Gurus,

 

I would just like to ask for some assistance on how I can achieve this result while in Power Query. I tried to do it in DAX using calculated columns, but I would like to do the transform while in Power Query as much as possible. Unfortunately, I am at a loss how to do this, as my knowledge is not there yet 😞

 

I have 2 tables:

Records Table:

Record IDMax Score
ID001400
ID002500
ID003200
Idxxx300

 

Data Table:

Record IDCategoryScore
ID001A50
ID002B200
ID001C100
ID001D150
ID003A50
IDxxxE75
IDxxxA75
ID002D100
ID003C75
ID003E50
ID002C150

 

What I would like to achieve is to add new columns in the record table that will put the category scores, the total score and the percent score (Total Cat Score / Max Score *100) such that the resulting table will be similar to this:

 

Records Table (Final Result)

Record IDMax ScoreCat ACat BCat CCat DCat ECat FTotal Cat ScorePct Score
ID0014005001001500030075.00
ID00250002001501000045090.00
ID00320050075050017587.50
Idxxx3007500075015050.00

 

Will this be possible to do just within Power Query? If so, can you help me how I can do this in Power Query?

 

Appreciate any help in advance!

1 ACCEPTED SOLUTION
v-yingjl
Community Support
Community Support

Hi @roosechua ,

You can try this query in the Records Table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8nQxMDBU0lEyMTBQitWB8I2AfFMkvjGQbwTnV1RUAPnGIH4sAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Record ID" = _t, #"Max Score" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Record ID", type text}, {"Max Score", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Category", each List.Distinct(Data[Category])),
    #"Expanded Category" = Table.ExpandListColumn(#"Added Custom", "Category"),
    #"Merged Queries" = Table.NestedJoin(#"Expanded Category", {"Record ID", "Category"}, Data, {"Record ID", "Category"}, "Data", JoinKind.LeftOuter),
    #"Expanded Data" = Table.ExpandTableColumn(#"Merged Queries", "Data", {"Score"}, {"Data.Score"}),
    #"Sorted Rows" = Table.Sort(#"Expanded Data",{{"Record ID", Order.Ascending}, {"Category", Order.Ascending}}),
    #"Added Custom1" = Table.AddColumn(#"Sorted Rows", "Total Cat Score", each let id = [Record ID] in List.Sum(Table.SelectRows(#"Sorted Rows", each [Record ID] = id)[Data.Score]),type number),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Cat", each "Cat " & [Category], type text),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Category"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Cat]), "Cat", "Data.Score"),
    #"Reordered Columns" = Table.ReorderColumns(#"Pivoted Column",{"Record ID", "Max Score", "Cat A", "Cat B", "Cat C", "Cat D", "Cat E", "Total Cat Score"}),
    #"Added Custom3" = Table.AddColumn(#"Reordered Columns", "Pct Score", each [Total Cat Score] / [Max Score] * 100, type number)
in
    #"Added Custom3"

vyingjl_0-1631842515621.png

 

Best Regards,
Community Support Team _ Yingjie Li
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
v-yingjl
Community Support
Community Support

Hi @roosechua ,

You can try this query in the Records Table:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8nQxMDBU0lEyMTBQitWB8I2AfFMkvjGQbwTnV1RUAPnGIH4sAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Record ID" = _t, #"Max Score" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Record ID", type text}, {"Max Score", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Category", each List.Distinct(Data[Category])),
    #"Expanded Category" = Table.ExpandListColumn(#"Added Custom", "Category"),
    #"Merged Queries" = Table.NestedJoin(#"Expanded Category", {"Record ID", "Category"}, Data, {"Record ID", "Category"}, "Data", JoinKind.LeftOuter),
    #"Expanded Data" = Table.ExpandTableColumn(#"Merged Queries", "Data", {"Score"}, {"Data.Score"}),
    #"Sorted Rows" = Table.Sort(#"Expanded Data",{{"Record ID", Order.Ascending}, {"Category", Order.Ascending}}),
    #"Added Custom1" = Table.AddColumn(#"Sorted Rows", "Total Cat Score", each let id = [Record ID] in List.Sum(Table.SelectRows(#"Sorted Rows", each [Record ID] = id)[Data.Score]),type number),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Cat", each "Cat " & [Category], type text),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Category"}),
    #"Pivoted Column" = Table.Pivot(#"Removed Columns", List.Distinct(#"Removed Columns"[Cat]), "Cat", "Data.Score"),
    #"Reordered Columns" = Table.ReorderColumns(#"Pivoted Column",{"Record ID", "Max Score", "Cat A", "Cat B", "Cat C", "Cat D", "Cat E", "Total Cat Score"}),
    #"Added Custom3" = Table.AddColumn(#"Reordered Columns", "Pct Score", each [Total Cat Score] / [Max Score] * 100, type number)
in
    #"Added Custom3"

vyingjl_0-1631842515621.png

 

Best Regards,
Community Support Team _ Yingjie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Thanks @v-yingjl! It worked perfectly!

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 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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