cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Helper I
Helper I

Sort names alphabetically but keeping groups with same ID together

I have a list of members of families attending an event that I want to sort alphabetically but some of the people have different surnames within the same family. I still want them to appear together in the list so grouped by ID which is the same for each family but placed alphabetically based on the name of Adult 1

 

Data starts as table 1

IDNameTitle
141SmithAdult 2 
141WardChild 3 
141WardChild 1 
141WardChild 2 
141WardAdult 1 
140RoseAdult 1 
140Brooks-RoseAdult 2 
138BudAdult 1 
136FilerAdult 2 
136FilerAdult 1 
120HeitlingerAdult 1 
120HeitlingerChild 2 
120HeitlingerChild 1 
120KarpAdult 2 
78CurwenAdult 1 
78CurwenAdult 2 
71PolinAdult 1 
71PolinAdult 2 
66CordellAdult 2 
66CordellAdult 1 
335FlaxAdult 1 
335JonesChild 1 
109GoldChild 3 
109GoldChild 1 
109GoldChild 2 
109Taylor-GoldAdult 2 
109GoldAdult 1 
171HillChild 1 
171HillAdult 2 
171HillChild 2 
171HillAdult 1 

 

Expected Output

IDNameTitle
138BudAdult 1 
66CordellAdult 2 
66CordellAdult 1 
78CurwenAdult 1 
78CurwenAdult 2 
136FilerAdult 2 
136FilerAdult 1 
335FlaxAdult 1 
335JonesChild 1 
109GoldAdult 1 
109Taylor-GoldAdult 2 
109GoldChild 1 
109GoldChild 2 
109GoldChild 3 
120HeitlingerAdult 1 
120KarpAdult 2 
120HeitlingerChild 1 
120HeitlingerChild 2 
171HillChild 1 
171HillAdult 2 
171HillChild 2 
171HillAdult 1 
71PolinAdult 1 
71PolinAdult 2 
140RoseAdult 1 
140Brooks-RoseAdult 2 
141WardAdult 1 
141SmithAdult 2 
141WardChild 1 
141WardChild 2 
141WardChild 3 
1 ACCEPTED SOLUTION
Super User III
Super User III

Hello @joooffice 

 

check out this solution. Used Table.Group to group by ID with all rows and the first name found. Then sort for this name and expand afterwards

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jZLNCsIwEIRfpeSsYBt/j1pQ0Yuo4KH0UEjQ4NpI2qK+vYm22rgJeArst7OT2SRJSNgPSYfsLqI86XPKKiiDKCBpp0GHTDF9xCcBLKBeEnqJa9rb56Pp6dJWFtxNZkrKc9G1GpqhdGwaKjyTDnVpLoArrMGoUUXGb8lFCSI//sXtjD5u6deZuv5eamRyxJW68fzX1IUalVnpRmozJMKk1gxN+lgqxgH+YvVESgdmbZDd3WQlc16gwL2JLi0k4C+EiV8Ttck+e4BU3brBftq21H6510KW4pXLtmsTexrWuMjXJ30C", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, Title = _t]),
    #"Changed Type" = Table.Buffer(Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"Title", type text}})),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"AllRows", each _, type table [ID=number, Name=text, Title=text]},{"NameToSort", each _[Name]{0}}}),
    #"Sorted Rows" = Table.Sort(#"Grouped Rows",{{"NameToSort", Order.Ascending}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Sorted Rows",{"AllRows"}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Removed Other Columns", "AllRows", {"ID", "Name", "Title"}, {"ID", "Name", "Title"})
in
    #"Expanded AllRows"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

1 REPLY 1
Super User III
Super User III

Hello @joooffice 

 

check out this solution. Used Table.Group to group by ID with all rows and the first name found. Then sort for this name and expand afterwards

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jZLNCsIwEIRfpeSsYBt/j1pQ0Yuo4KH0UEjQ4NpI2qK+vYm22rgJeArst7OT2SRJSNgPSYfsLqI86XPKKiiDKCBpp0GHTDF9xCcBLKBeEnqJa9rb56Pp6dJWFtxNZkrKc9G1GpqhdGwaKjyTDnVpLoArrMGoUUXGb8lFCSI//sXtjD5u6deZuv5eamRyxJW68fzX1IUalVnpRmozJMKk1gxN+lgqxgH+YvVESgdmbZDd3WQlc16gwL2JLi0k4C+EiV8Ttck+e4BU3brBftq21H6510KW4pXLtmsTexrWuMjXJ30C", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, Title = _t]),
    #"Changed Type" = Table.Buffer(Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"Title", type text}})),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"AllRows", each _, type table [ID=number, Name=text, Title=text]},{"NameToSort", each _[Name]{0}}}),
    #"Sorted Rows" = Table.Sort(#"Grouped Rows",{{"NameToSort", Order.Ascending}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Sorted Rows",{"AllRows"}),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Removed Other Columns", "AllRows", {"ID", "Name", "Title"}, {"ID", "Name", "Title"})
in
    #"Expanded AllRows"

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

Helpful resources

Announcements
secondImage

Congratulations!

We are excited to announce the Power BI Super Users!

Wave Release 2

Check out the updates in Power BI.

Overview of Power BI 2020 release wave 2!

Microsoft Ignite

Microsoft Ignite

Join digitally, March 2–4, 2021 to explore new tech that's ready to implement. Experience the keynote in mixed reality through AltspaceVR!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors