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
chudson
Helper IV
Helper IV

Power Query Custom Column or Some Sort OF Rank Based Off Multiple Columns

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. 

 

ProcessDayKeyBatchIDDesired Result
202011011231
202011011231
202011011231
202011014562
202011014562
202011014562
202011017893
202011017893
202011017893
202011028881
202011028881
202011028881
202011029992
202011029992
202011029992
2020110211113
2020110211113
2020110211113

 

Thanks!

Chris

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

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"

index.JPG

 

 

Best regards

Icey

 

If this post helps, then consider Accepting it as the solution to help other members find it faster.

View solution in original post

4 REPLIES 4
Icey
Community Support
Community Support

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"

index.JPG

 

 

Best regards

Icey

 

If this post helps, then consider Accepting it as the solution to help other members find it faster.

Jimmy801
Community Champion
Community Champion

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

Jimmy801
Community Champion
Community Champion

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

Jimmy801_0-1605766859805.png

b) Add the new columns in the expand-step

Jimmy801_1-1605766894573.png

 

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

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.