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

Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more

Reply
Berean_50
Helper I
Helper I

How to group rows dynamically

Given the following input:

Berean_50_0-1639377547224.png

the goal is to produce the following output where the table is grouped by the static columns Name and Period. The challenging aspect of this task is that Category A, Category B, Category C are dynamic columns. There could be one or more columns by different names. That means we can't refer to these columns by name.

The desired output is the following:

Berean_50_1-1639377721752.png


Assumptions:

  1. Name and Period columns are always known and are used in the Group By.
  2. The variable columns will always start at position 3.
  3. There could be one or more dynamic columns.
  4. The last dynamic column (in this case, Category C) will always be the last column on the table.

I can produce the right results using Power Query UI to group rows. However, since I don't know what the dynamic columns are I would need to refer to the list of columns using column indexes. That's where the challenge is. Any help on how to get the desired results would be hugely appreciated.

Here's the source test file:

https://1drv.ms/x/s!AuHocvOERo6IhNoIl4d1ax2SjTgXSA?e=uO4bd5



 

1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

How about this?

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    DynamicColumns = List.RemoveItems(Table.ColumnNames(Source), {"Name", "Period"}),
    #"Grouped Rows" = Table.Group(Source, {"Name", "Period"},
        List.Transform(DynamicColumns, (col) => {col, each List.Max(Table.Column(_, col)), type text}))
in
    #"Grouped Rows"

 

This takes the column names other than "Name" and "Period" and maxes over them in a Group By step.

View solution in original post

3 REPLIES 3
AlexisOlson
Super User
Super User

How about this?

 

let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    DynamicColumns = List.RemoveItems(Table.ColumnNames(Source), {"Name", "Period"}),
    #"Grouped Rows" = Table.Group(Source, {"Name", "Period"},
        List.Transform(DynamicColumns, (col) => {col, each List.Max(Table.Column(_, col)), type text}))
in
    #"Grouped Rows"

 

This takes the column names other than "Name" and "Period" and maxes over them in a Group By step.

@AlexisOlson 
This is very clever piece of code. Brilliant! I learned something today. Unfortunately all I can afford is to say "Thank You".

Thingsclump
Resolver V
Resolver V

Hi @Berean_50 

 

For challenging part, I would recommend to rename 3rd, 4th and 5th column in PQ initially by referring position. You can use "Table.RenameColumns" using position. This way all steps downstream are not impacted. 

 

Thankyou

Thingsclump

www.thingsclump.com 

 

 

Helpful resources

Announcements
PBIApril_Carousel

Power BI Monthly Update - April 2025

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

Notebook Gallery Carousel1

NEW! Community Notebooks Gallery

Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.

April2025 Carousel

Fabric Community Update - April 2025

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