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

Assign identifier to rows using multiple columns

I'm attempting to identify duplicate groups and assign identifiers based on 2 columns, Name and SSN:

 

Group IDNameSSN
 Jane Doe111111111
 Jane Doe222222222
 Jane Doe111111111
 John Doe333333333
 John Doe 

 

Match criteria is both Name and SSN match or Name matches and SSN is blank:

 

Group IDNameSSN
1Jane Doe111111111
2Jane Doe222222222
1Jane Doe111111111
3John Doe333333333
3John Doe 

 

Any help is much appreciated!

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

you can Fill-down the SSN-column, Group by Name and SSN and add a index column. Expand the grouped table afterwards. Here the M-code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMS1VwyU9V0lEyhAGlWB0UCSMYQJdA05GfkQeVMIYBdAkFpdhYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, SSN = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"SSN", Int64.Type}}),
    #"Filled Down" = Table.FillDown(#"Changed Type",{"SSN"}),
    #"Grouped Rows" = Table.Group(#"Filled Down", {"Name", "SSN"}, {{"AllRows", each _, type table [Name=text, SSN=number]}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Grouped Rows",{"AllRows"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Other Columns", "Index", 1, 1),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Index", "AllRows", {"Name", "SSN"}, {"Name", "SSN"})
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

2 REPLIES 2
Anonymous
Not applicable

@Jimmy801 Genius! Thank you very much!

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

you can Fill-down the SSN-column, Group by Name and SSN and add a index column. Expand the grouped table afterwards. Here the M-code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8krMS1VwyU9V0lEyhAGlWB0UCSMYQJdA05GfkQeVMIYBdAkFpdhYAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, SSN = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"SSN", Int64.Type}}),
    #"Filled Down" = Table.FillDown(#"Changed Type",{"SSN"}),
    #"Grouped Rows" = Table.Group(#"Filled Down", {"Name", "SSN"}, {{"AllRows", each _, type table [Name=text, SSN=number]}}),
    #"Removed Other Columns" = Table.SelectColumns(#"Grouped Rows",{"AllRows"}),
    #"Added Index" = Table.AddIndexColumn(#"Removed Other Columns", "Index", 1, 1),
    #"Expanded AllRows" = Table.ExpandTableColumn(#"Added Index", "AllRows", {"Name", "SSN"}, {"Name", "SSN"})
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

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