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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

Selecting top 2 people from each ID - DAX or PowerQuery

I have a table with IDs and names and I only want to pick top 2 names (alphabetically).. is there a way to achieve this via DAX or in Power Query? I can't do TOP N function since I need to merge several different tables later on so need a logic applied for each table before I merge them by ID. 

Any help/advice would be appreciated!

 

 
1.png
1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

Group by the ID column and choose All Rows as the Operation:

AlexisOlson_0-1672778665177.png

This is the result:

AlexisOlson_1-1672778726461.png

 

Tweak the generated code slightly to only get the top 2 names. Change "each _" to:

each Table.MinN(_, "Name", 2)

Expand the Name column (or all of the non-ID columns) and you're done!

AlexisOlson_2-1672778899374.png

 

Full sample code you can paste into the Advanced Editor of a new blank query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXLMrVSK1YGwPRIzc1IR3ODEXDjbMbM4A8wxAnKcEOpAXOfMvBQEzyc1Fcw2BrJDEivhbI/EoiIEzzszF852zEmtQOLkZAINiAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"Subtable", each Table.MinN(_, "Name", 2), type table [ID=nullable number, Name=nullable text]}}),
    #"Expanded Subtable" = Table.ExpandTableColumn(#"Grouped Rows", "Subtable", {"Name"}, {"Name"})
in
    #"Expanded Subtable"

 

View solution in original post

1 REPLY 1
AlexisOlson
Super User
Super User

Group by the ID column and choose All Rows as the Operation:

AlexisOlson_0-1672778665177.png

This is the result:

AlexisOlson_1-1672778726461.png

 

Tweak the generated code slightly to only get the top 2 names. Change "each _" to:

each Table.MinN(_, "Name", 2)

Expand the Name column (or all of the non-ID columns) and you're done!

AlexisOlson_2-1672778899374.png

 

Full sample code you can paste into the Advanced Editor of a new blank query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUXLMrVSK1YGwPRIzc1IR3ODEXDjbMbM4A8wxAnKcEOpAXOfMvBQEzyc1Fcw2BrJDEivhbI/EoiIEzzszF852zEmtQOLkZAINiAUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"ID"}, {{"Subtable", each Table.MinN(_, "Name", 2), type table [ID=nullable number, Name=nullable text]}}),
    #"Expanded Subtable" = Table.ExpandTableColumn(#"Grouped Rows", "Subtable", {"Name"}, {"Name"})
in
    #"Expanded Subtable"

 

Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors