Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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
|
Data Table:
Record IDCategoryScore
|
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
|
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!
Solved! Go to Solution.
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"
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.
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"
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.
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
10 | |
7 | |
6 | |
6 | |
6 |