cancel
Showing results for 
Search instead for 
Did you mean: 
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

8 REPLIES 8
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. 

MarcelBeug
Community Champion
Community Champion

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 IV
Super User IV

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!!!

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Agreed, but this was requested strongly from the users.

MarcelBeug
Community Champion
Community Champion

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)

View solution in original post

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
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

Top Solution Authors
Top Kudoed Authors