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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
stu-co
Regular Visitor

Sorting a dynamic number of columns alphanumerically

So I've got a Power Query script that at one point pivots a table.

 

This creates a dynamic number of columns.

 

One of these columns is text, but will usually have a value at the front such as `1. this is a description`, `2. this is another description` etc, up to `34. this is a description.`

 

PowerQuery is sorting these columns alphabetically left to right. However, I would like to sort them by number.

 

As the number of columns is variable, as are the column names, I cannot Reorder by the explicit column names.

I'm a bit stuck here, so any help would do!

1 ACCEPTED SOLUTION

The code below will numerically sort the columns that have a name with a number before the dot.

I assume there are also columns without number.

 

let
    Source = Table1,
    ColumnNames = #table(1,List.Zip({Table.ColumnNames(Source)})),
    #"Inserted Text Before Delimiter" = Table.AddColumn(ColumnNames, "Text Before Delimiter", each Text.BeforeDelimiter([Column1], ".", 0), type text),
    #"Changed Type" = Table.TransformColumnTypes(#"Inserted Text Before Delimiter",{{"Text Before Delimiter", Int64.Type}}),
    #"Removed Errors" = Table.RemoveRowsWithErrors(#"Changed Type", {"Text Before Delimiter"}),
    #"Sorted Rows" = Table.Sort(#"Removed Errors",{{"Text Before Delimiter", Order.Ascending}}),
    NewColumnOrder = #"Sorted Rows"[Column1],
    ReorderedColumns = Table.ReorderColumns(Source,NewColumnOrder)
in
    ReorderedColumns
Specializing in Power Query Formula Language (M)

View solution in original post

9 REPLIES 9
dasg777
New Member

I had almost the same problem sorting my dynamic columns. I have dynamic columns because my source files change based on Dates. Unfortunately, the file columns names are literal Dates, like 27/03/2022, 28/03/2022 etc. And could be different anytime I run the process. (I run a Table.Combine to gather all the files within a path tree)

I tried several things, but the one that worked really well for me was this.

Lets make this example with 10 columns (this number is dynamic, maybe tomorrow could be 20), and 7 out of them have a Date as name, the other 3 columns never change ("Name", "Description" and "Country")

This is what I did. I selected the 3 columns that never change, then perform an "Unpivot other columns". Then I sorted the table over the "Attribute" column (the column wich is generated when you perform the unpivot, as well as the column "value").

Then, after sorting the "Attribute" column, I performed a Pivot on the same column "Attribute". And in the dialog box I selected "Values column" = Value (this column was generated in the Unpivot step), and then clicked on the advanced options to select "Don't aggregate" function.

And that did the trick. This always works even when new columns are added to the files.



 

stu-co
Regular Visitor

So I am getting the following error on List.Zip.

 

`Expression.Error: The import List.Zip matches no exports. Did you miss a module reference?`

 

I will be spending some time googling it soon. 

According to my documentation, List.Zip was added in Power BI Desktop in September 2016.

Specializing in Power Query Formula Language (M)
Greg_Deckler
Super User
Super User

Dynamic numbers of columns is generally bad. Can you post a sample of the source data and what you are transforming it into? @MarcelBeug generally has quite a few tricks or this sort of thing.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Agreed, but this was requested strongly from the users.

Do you refer to the remark that numbering columns is bad?

 

How about your feedback on the other contributions?

Specializing in Power Query Formula Language (M)

Yes I do, I just assumed that the forum would show other users which post I had hit reply to!

 

I haven't tested your solution yet, but it looks promising.

The code below will numerically sort the columns that have a name with a number before the dot.

I assume there are also columns without number.

 

let
    Source = Table1,
    ColumnNames = #table(1,List.Zip({Table.ColumnNames(Source)})),
    #"Inserted Text Before Delimiter" = Table.AddColumn(ColumnNames, "Text Before Delimiter", each Text.BeforeDelimiter([Column1], ".", 0), type text),
    #"Changed Type" = Table.TransformColumnTypes(#"Inserted Text Before Delimiter",{{"Text Before Delimiter", Int64.Type}}),
    #"Removed Errors" = Table.RemoveRowsWithErrors(#"Changed Type", {"Text Before Delimiter"}),
    #"Sorted Rows" = Table.Sort(#"Removed Errors",{{"Text Before Delimiter", Order.Ascending}}),
    NewColumnOrder = #"Sorted Rows"[Column1],
    ReorderedColumns = Table.ReorderColumns(Source,NewColumnOrder)
in
    ReorderedColumns
Specializing in Power Query Formula Language (M)
stu-co
Regular Visitor

So I've got a Power Query script that at one point pivots a table.

 

This creates a dynamic number of columns.

 

One of these columns is text, but will usually have a value at the front such as `1. this is a description`, `2. this is another description` etc, up to `34. this is a description.`

 

PowerQuery is sorting these columns alphabetically left to right. However, I would like to sort them by number.

 

As the number of columns is variable, as are the column names, I cannot Reorder by the explicit column names.

I'm a bit stuck here, so any help would do!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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