Microsoft is giving away 50,000 FREE Microsoft Certification exam vouchers. Get Fabric certified for FREE! Learn more
Given the following input:
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:
Assumptions:
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
Solved! Go to Solution.
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.
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".
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
Check out the April 2025 Power BI update to learn about new features.
Explore and share Fabric Notebooks to boost Power BI insights in the new community notebooks gallery.
User | Count |
---|---|
20 | |
11 | |
10 | |
8 | |
7 |