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.
Does anyone know an easy way in the Power Query to create a ranking based off of a few columns in the dataset? I have a Fact Table that is processed 3 times a day and instead of wiping out the data each time it combines them all (don't ask me why) so at the end of each day i have 3 batches of data. Essentially, I want to create a rank or category of 1-3 based off of each process day key and batchid that day that way I can filter for only the first or last batch on each day instead of bringing in all 3 batches of data. Below is a simplfied example with the desired result.
ProcessDayKey | BatchID | Desired Result |
20201101 | 123 | 1 |
20201101 | 123 | 1 |
20201101 | 123 | 1 |
20201101 | 456 | 2 |
20201101 | 456 | 2 |
20201101 | 456 | 2 |
20201101 | 789 | 3 |
20201101 | 789 | 3 |
20201101 | 789 | 3 |
20201102 | 888 | 1 |
20201102 | 888 | 1 |
20201102 | 888 | 1 |
20201102 | 999 | 2 |
20201102 | 999 | 2 |
20201102 | 999 | 2 |
20201102 | 1111 | 3 |
20201102 | 1111 | 3 |
20201102 | 1111 | 3 |
Thanks!
Chris
Solved! Go to Solution.
Hi @chudson ,
Try this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMjA0NDBU0lEyNDJWitUhQ8jE1Iw8IXMLS9KFjIBCFhYW5AlZWmKYRZyQIRAQLxYLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ProcessDayKey = _t, BatchID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ProcessDayKey", Int64.Type}, {"BatchID", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ProcessDayKey", "BatchID"}, {{"All", each _, type table [ProcessDayKey=nullable number, BatchID=nullable number]}}),
#"Grouped Rows1" = Table.Group(#"Grouped Rows", {"ProcessDayKey"}, {{"All", (tableint) => let sort = Table.Sort(tableint,{"BatchID", Order.Ascending}), AddIndex = Table.AddIndexColumn(sort,"Index",1) in AddIndex}}),
#"Expanded All" = Table.ExpandTableColumn(#"Grouped Rows1", "All", {"All", "Index"}, {"All.1", "Index"}),
#"Expanded All.1" = Table.ExpandTableColumn(#"Expanded All", "All.1", {"BatchID"}, {"BatchID"})
in
#"Expanded All.1"
Best regards
Icey
If this post helps, then consider Accepting it as the solution to help other members find it faster.
Hi @chudson ,
Try this:
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMjA0NDBU0lEyNDJWitUhQ8jE1Iw8IXMLS9KFjIBCFhYW5AlZWmKYRZyQIRAQLxYLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ProcessDayKey = _t, BatchID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ProcessDayKey", Int64.Type}, {"BatchID", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ProcessDayKey", "BatchID"}, {{"All", each _, type table [ProcessDayKey=nullable number, BatchID=nullable number]}}),
#"Grouped Rows1" = Table.Group(#"Grouped Rows", {"ProcessDayKey"}, {{"All", (tableint) => let sort = Table.Sort(tableint,{"BatchID", Order.Ascending}), AddIndex = Table.AddIndexColumn(sort,"Index",1) in AddIndex}}),
#"Expanded All" = Table.ExpandTableColumn(#"Grouped Rows1", "All", {"All", "Index"}, {"All.1", "Index"}),
#"Expanded All.1" = Table.ExpandTableColumn(#"Expanded All", "All.1", {"BatchID"}, {"BatchID"})
in
#"Expanded All.1"
Best regards
Icey
If this post helps, then consider Accepting it as the solution to help other members find it faster.
Hello @chudson
you can use Table.Group and then add a Index-column. Afterwards expand the grouped table. Here the M-code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjIwMjA0NDBU0lEyNDJWitUhQ8jE1Iw8IXMLS9KFjIBCFhYW5AlZWmKYRZyQIRAQLxYLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ProcessDayKey = _t, BatchID = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ProcessDayKey", Int64.Type}, {"BatchID", Int64.Type}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"ProcessDayKey", "BatchID"}, {{"AllRows", each _, type table [ProcessDayKey=number, BatchID=number]}}),
#"Removed Other Columns" = Table.SelectColumns(#"Grouped Rows",{"AllRows"}),
#"Added Index" = Table.AddIndexColumn(#"Removed Other Columns", "Index", 1, 1),
#"Expanded AllRows" = Table.ExpandTableColumn(#"Added Index", "AllRows", {"ProcessDayKey", "BatchID"}, {"ProcessDayKey", "BatchID"})
in
#"Expanded AllRows"
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
Hi @Jimmy801 ,
I took some of your code and used it the only thing is I would like my All rows section not to be limited to just the processdaykey and batchid columns, i would like pretty much all other columns in the fact table to remain. Is there easy way to include that into the M code? Also, the index numbers aren't only coming out as 1-3.
Thanks,
Chris
Hello @chudson
you have to enhance
a) the 2nd parameter of the Table.Group. You can do this also in the GUI by clicking on the settings of this step
b) Add the new columns in the expand-step
If you have more then 3 groups, power query will add as much as needed.
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
Check out the July 2025 Power BI update to learn about new features.
User | Count |
---|---|
7 | |
5 | |
5 | |
5 | |
4 |
User | Count |
---|---|
12 | |
11 | |
9 | |
7 | |
6 |