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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
coffeexyz
Regular Visitor

PowerQuery sort and index on subgroup

Hi, 

I want to sort the data on a table with creating an index and subindex column. The original data table is similar to the following layout, but with more customer and SKUs. 

 

CustomerDate SKUQuantityPrice
A1/1/2026 X5010
A1/1/2026 X1012
A1/1/2026 X115
A1/5/2026 X1011
A1/5/2026 X114
A1/5/2026 X509

 

I had trouble using PowerQuery's groupby function to index and sort it to the following format. 

I want to be able to index by Customer & Date & SKU,  with the sub-index by sorted ascending Quantity. The table output I wanted is listed below. Any pointers would be appreciated!

CustomerDate SKUQuantityPriceIndex by QuantitySub -index by Date
A1/1/2026 X501031
A1/1/2026 X101221
A1/1/2026 X11511
A1/5/2026 X101122
A1/5/2026 X11412
A1/5/2026 X50932
1 ACCEPTED SOLUTION

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTLUN9Q3MjAyAzIjgNjUACRmoBSrg1XaECxthFMahE2RZE0xNRvilAZhE1yyYIdZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, SKU = _t, Quantity = _t, Price = _t]),
    #"Grouped Rows" = Table.Group(Source, {"Customer", "Date", "SKU"}, {{"Rows", each Table.AddIndexColumn(Table.Sort(Table.SelectColumns(_,{"Quantity","Price"}),{"Quantity",Order.Descending}), "Quantity Index", 1, 1, Int64.Type)}}),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Date Index", 1, 1, Int64.Type),
    #"Expanded Rows" = Table.ExpandTableColumn(#"Added Index", "Rows", {"Quantity", "Price", "Quantity Index"}, {"Quantity", "Price", "Quantity Index"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded Rows",{{"Quantity", Int64.Type}, {"Price", Currency.Type}, {"Quantity Index", Int64.Type}, {"Date", type date}})
in
    #"Changed Type1"

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done". Once you examined the code, replace the entire Source step with your own source.

View solution in original post

4 REPLIES 4
ronrsnfld
Super User
Super User

Paste the code below into the advanced editor to see a method of doing this

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTLUN9Q3MjAyAzIjgNjUACRmoBSrg1XaECxthFMahE2RZE0xNRvilAZhE1yyYIdZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, SKU = _t, Quantity = _t, Price = _t]),
    
    #"Grouped Rows" = Table.Group(Source, {"Customer"}, {
        {"Added Index Columns",(t)=>
            [a=Table.AddIndexColumn(t,"Index",0,1, Int64.Type), //enable original order restore
             b=Table.AddRankColumn(a,"Quantity Index",
                 {"Quantity", Order.Ascending}, [RankKind=RankKind.Dense]),
             c=Table.AddRankColumn(b,"Date Sub-Index", {"Date", Order.Ascending},[RankKind=RankKind.Dense]),
             d=Table.Sort(c,{"Index",Order.Ascending}) //Return to original Order
             ][d],
                type table [Customer=nullable text, Date=nullable date, SKU=nullable text, 
                    Quantity=nullable number, Price=nullable number, Quantity Index=Int64.Type, #"Date Sub-Index"=Int64.Type]        
        }}),
    
    #"Expanded Added Index Columns" = Table.ExpandTableColumn(#"Grouped Rows", "Added Index Columns",
      {"Date", "SKU", "Quantity", "Price", "Quantity Index", "Date Sub-Index"})
in
    #"Expanded Added Index Columns"

Original Data:

ronrsnfld_0-1767903965249.png

Results

ronrsnfld_1-1767903989903.png

 

 

 

lbendlin
Super User
Super User

This is very expensive to do in Power Query as it breaks the streaming.  Can you do that in Power BI instead?

Would like to use the sub-index column to pivot the table,  the row data of Quantity and Price into columns. 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WclTSUTLUN9Q3MjAyAzIjgNjUACRmoBSrg1XaECxthFMahE2RZE0xNRvilAZhE1yyYIdZKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, SKU = _t, Quantity = _t, Price = _t]),
    #"Grouped Rows" = Table.Group(Source, {"Customer", "Date", "SKU"}, {{"Rows", each Table.AddIndexColumn(Table.Sort(Table.SelectColumns(_,{"Quantity","Price"}),{"Quantity",Order.Descending}), "Quantity Index", 1, 1, Int64.Type)}}),
    #"Added Index" = Table.AddIndexColumn(#"Grouped Rows", "Date Index", 1, 1, Int64.Type),
    #"Expanded Rows" = Table.ExpandTableColumn(#"Added Index", "Rows", {"Quantity", "Price", "Quantity Index"}, {"Quantity", "Price", "Quantity Index"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Expanded Rows",{{"Quantity", Int64.Type}, {"Price", Currency.Type}, {"Quantity Index", Int64.Type}, {"Date", type date}})
in
    #"Changed Type1"

How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done". Once you examined the code, replace the entire Source step with your own source.

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors