Merge rows keeping all data

inactiveUser333473

New Member
Joined
Jul 10, 2015
Messages
45
Hi, I have searched for this elsewhere but cannot find a solved solution.

In table one I have the data as it would be, in table two I have the data as I would want it.

Can anyone help?

Name Surname Org Title Team 1 Skill 1 Skill 2 Skill 3 Skill 4 Skill 5 Skill 6 Skill 7 Skill 8 Gender In Contract
Terry Wogan BBC Host Team 1 L2 m
Terry Wogan BBC Host Team 1 Res m
Terry Wogan BBC Host Team 1 Cdr m
Terry Wogan BBC Host Team 1 Bas m
Terry Wogan BBC Host Team 1 Adv m

Name Surname Org Title Team 1 Skill 1 Skill 2 Skill 3 Skill 4 Skill 5 Skill 6 Skill 7 Skill 8 Gender In Contract
Terry Wogan BBC Host Team 1 Adv Res Cdr Bas L2 m
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
It is not clear what you have in what columns and same for the results. Check my signature block below for better ways to display sample data.
 
Upvote 0
Just taking a wild guess, but have you tried the =CONCATENATE() command? to get spaces between the cells you can use ,&" "&,

=CONCATENATE(A1,&" "&,B1,&" "&,C1...)

could do the trick.
 
Upvote 0
Sorry, I uploaded that using my phone and the format has changed somewhat, it should look like this.

[TABLE="class: grid, width: 929"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Surname[/TD]
[TD]Org[/TD]
[TD]Title[/TD]
[TD]Team 1[/TD]
[TD]Skill 1[/TD]
[TD]Skill 2[/TD]
[TD]Skill 3[/TD]
[TD]Skill 4[/TD]
[TD]Skill 5[/TD]
[TD]Skill 6[/TD]
[TD]Skill 7[/TD]
[TD]Skill 8[/TD]
[TD]Gender[/TD]
[TD]In Contract[/TD]
[/TR]
[TR]
[TD]Terry[/TD]
[TD]Wogan[/TD]
[TD]BBC[/TD]
[TD]Host[/TD]
[TD]Team 1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]L2[/TD]
[TD][/TD]
[TD][/TD]
[TD]m[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Terry[/TD]
[TD]Wogan[/TD]
[TD]BBC[/TD]
[TD]Host[/TD]
[TD]Team 1[/TD]
[TD][/TD]
[TD]Res[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]m[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Terry[/TD]
[TD]Wogan[/TD]
[TD]BBC[/TD]
[TD]Host[/TD]
[TD]Team 1[/TD]
[TD][/TD]
[TD][/TD]
[TD]Cdr[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]m[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Terry[/TD]
[TD]Wogan[/TD]
[TD]BBC[/TD]
[TD]Host[/TD]
[TD]Team 1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]Bas[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]m[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Terry[/TD]
[TD]Wogan[/TD]
[TD]BBC[/TD]
[TD]Host[/TD]
[TD]Team 1[/TD]
[TD]Adv[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]m[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


and table 2

[TABLE="class: grid, width: 929"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Surname[/TD]
[TD]Org[/TD]
[TD]Title[/TD]
[TD]Team 1[/TD]
[TD]Skill 1[/TD]
[TD]Skill 2[/TD]
[TD]Skill 3[/TD]
[TD]Skill 4[/TD]
[TD]Skill 5[/TD]
[TD]Skill 6[/TD]
[TD]Skill 7[/TD]
[TD]Skill 8[/TD]
[TD]Gender[/TD]
[TD]In Contract[/TD]
[/TR]
[TR]
[TD]Terry[/TD]
[TD]Wogan[/TD]
[TD]BBC[/TD]
[TD]Host[/TD]
[TD]Team 1[/TD]
[TD]Adv[/TD]
[TD]Res[/TD]
[TD]Cdr[/TD]
[TD]Bas[/TD]
[TD][/TD]
[TD]L2[/TD]
[TD][/TD]
[TD][/TD]
[TD]m[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
PowerQuery (aka Get&Transform)

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]Name[/td][td=bgcolor:#5B9BD5]Surname[/td][td=bgcolor:#5B9BD5]Org[/td][td=bgcolor:#5B9BD5]Title[/td][td=bgcolor:#5B9BD5]Team 1[/td][td=bgcolor:#5B9BD5]Skill 1[/td][td=bgcolor:#5B9BD5]Skill 2[/td][td=bgcolor:#5B9BD5]Skill 3[/td][td=bgcolor:#5B9BD5]Skill 4[/td][td=bgcolor:#5B9BD5]Skill 5[/td][td=bgcolor:#5B9BD5]Skill 6[/td][td=bgcolor:#5B9BD5]Skill 7[/td][td=bgcolor:#5B9BD5]Skill 8[/td][td=bgcolor:#5B9BD5]Gender[/td][td=bgcolor:#5B9BD5]In Contract[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Terry[/td][td=bgcolor:#DDEBF7]Wogan[/td][td=bgcolor:#DDEBF7]BBC[/td][td=bgcolor:#DDEBF7]Host[/td][td=bgcolor:#DDEBF7]Team 1[/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7]L2[/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7]m[/td][td=bgcolor:#DDEBF7][/td][/tr]

[tr=bgcolor:#FFFFFF][td]Terry[/td][td]Wogan[/td][td]BBC[/td][td]Host[/td][td]Team 1[/td][td][/td][td]Res[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td]m[/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Terry[/td][td=bgcolor:#DDEBF7]Wogan[/td][td=bgcolor:#DDEBF7]BBC[/td][td=bgcolor:#DDEBF7]Host[/td][td=bgcolor:#DDEBF7]Team 1[/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7]Cdr[/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7]m[/td][td=bgcolor:#DDEBF7][/td][/tr]

[tr=bgcolor:#FFFFFF][td]Terry[/td][td]Wogan[/td][td]BBC[/td][td]Host[/td][td]Team 1[/td][td][/td][td][/td][td][/td][td]Bas[/td][td][/td][td][/td][td][/td][td][/td][td]m[/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]Terry[/td][td=bgcolor:#DDEBF7]Wogan[/td][td=bgcolor:#DDEBF7]BBC[/td][td=bgcolor:#DDEBF7]Host[/td][td=bgcolor:#DDEBF7]Team 1[/td][td=bgcolor:#DDEBF7]Adv[/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7][/td][td=bgcolor:#DDEBF7]m[/td][td=bgcolor:#DDEBF7][/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#70AD47]Name[/td][td=bgcolor:#70AD47]Surname[/td][td=bgcolor:#70AD47]Org[/td][td=bgcolor:#70AD47]Title[/td][td=bgcolor:#70AD47]Team 1[/td][td=bgcolor:#70AD47]Skill 1[/td][td=bgcolor:#70AD47]Skill 2[/td][td=bgcolor:#70AD47]Skill 3[/td][td=bgcolor:#70AD47]Skill 4[/td][td=bgcolor:#70AD47]Skill 5[/td][td=bgcolor:#70AD47]Skill 6[/td][td=bgcolor:#70AD47]Skill 7[/td][td=bgcolor:#70AD47]Skill 8[/td][td=bgcolor:#70AD47]Gender[/td][td=bgcolor:#70AD47]In Contract[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#E2EFDA]Terry[/td][td=bgcolor:#E2EFDA]Wogan[/td][td=bgcolor:#E2EFDA]BBC[/td][td=bgcolor:#E2EFDA]Host[/td][td=bgcolor:#E2EFDA]Team 1[/td][td=bgcolor:#E2EFDA]Adv[/td][td=bgcolor:#E2EFDA]Res[/td][td=bgcolor:#E2EFDA]Cdr[/td][td=bgcolor:#E2EFDA]Bas[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA]L2[/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA][/td][td=bgcolor:#E2EFDA]m[/td][td=bgcolor:#E2EFDA][/td][/tr]
[/table]

Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table3"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Name", type text}, {"Surname", type text}, {"Org", type text}, {"Title", type text}, {"Team 1", type text}, {"Skill 1", type text}, {"Skill 2", type text}, {"Skill 3", type text}, {"Skill 4", type text}, {"Skill 5", type any}, {"Skill 6", type text}, {"Skill 7", type any}, {"Skill 8", type any}, {"Gender", type text}, {"In Contract", type any}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Name", "Surname", "Org", "Title", "Team 1"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Skill 1", each Table.Column([Count],"Skill 1")),
    #"Extracted Values" = Table.TransformColumns(#"Added Custom", {"Skill 1", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom1" = Table.AddColumn(#"Extracted Values", "Skill 2", each Table.Column([Count],"Skill 2")),
    #"Extracted Values1" = Table.TransformColumns(#"Added Custom1", {"Skill 2", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom2" = Table.AddColumn(#"Extracted Values1", "Skill 3", each Table.Column([Count],"Skill 3")),
    #"Extracted Values2" = Table.TransformColumns(#"Added Custom2", {"Skill 3", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom3" = Table.AddColumn(#"Extracted Values2", "Skill 4", each Table.Column([Count],"Skill 4")),
    #"Extracted Values3" = Table.TransformColumns(#"Added Custom3", {"Skill 4", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom4" = Table.AddColumn(#"Extracted Values3", "Skill 5", each Table.Column([Count],"Skill 5")),
    #"Extracted Values4" = Table.TransformColumns(#"Added Custom4", {"Skill 5", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom5" = Table.AddColumn(#"Extracted Values4", "Skill 6", each Table.Column([Count],"Skill 6")),
    #"Extracted Values5" = Table.TransformColumns(#"Added Custom5", {"Skill 6", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom6" = Table.AddColumn(#"Extracted Values5", "Skill 7", each Table.Column([Count],"Skill 7")),
    #"Extracted Values6" = Table.TransformColumns(#"Added Custom6", {"Skill 7", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom7" = Table.AddColumn(#"Extracted Values6", "Skill 8", each Table.Column([Count],"Skill 8")),
    #"Extracted Values7" = Table.TransformColumns(#"Added Custom7", {"Skill 8", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom8" = Table.AddColumn(#"Extracted Values7", "Gender", each List.Distinct(Table.Column([Count],"Gender"))),
    #"Extracted Values8" = Table.TransformColumns(#"Added Custom8", {"Gender", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    #"Added Custom9" = Table.AddColumn(#"Extracted Values8", "In Contract", each Table.Column([Count],"In Contract")),
    #"Extracted Values9" = Table.TransformColumns(#"Added Custom9", {"In Contract", each Text.Combine(List.Transform(_, Text.From), " "), type text})
in
    #"Extracted Values9"[/SIZE]
 
Upvote 0
See if this is heading in the right direction.
Test in a copy of your workbook

Code:
Sub MergeToOneRow()
  Dim a As Variant, b As Variant
  Dim i As Long, j As Long, k As Long, uba2 As Long
  
  With Range("A1").CurrentRegion
    a = .Resize(.Rows.Count + 1).Value
    uba2 = UBound(a, 2)
    ReDim b(1 To UBound(a, 1), 1 To uba2)
    For i = 2 To UBound(a) - 1
      If Join(Application.Index(a, i, Array(1, 2, 3, 4, 5)), "|") <> Join(Application.Index(a, i - 1, Array(1, 2, 3, 4, 5)), "|") Then
        k = k + 1
        For j = 1 To 5
          b(k, j) = a(i, j)
        Next j
      End If
      For j = 6 To uba2
        If Len(a(i, j)) > 0 Then b(k, j) = a(i, j)
      Next j
    Next i
    .Offset(.Rows.Count + 2).Resize(k).Value = b
  End With
End Sub

My sample data in rows 1:6 with results of the code below that (you didn't say where to put the results).


Excel 2016
ABCDEFGHIJKLMNO
1NameSurnameOrgTitleTeam 1Skill 1Skill 2Skill 3Skill 4Skill 5Skill 6Skill 7Skill 8GenderIn Contract
2TerryWoganBBCHostTeam 1L2m
3TerryWoganBBCHostTeam 1Resm
4TerryWoganBBCHostTeam 1Cdrm
5TerryWoganBBCHostTeam 1Basm
6TerryWoganBBCHostTeam 1Advm
7
8
9TerryWoganBBCHostTeam 1AdvResCdrBasL2m
Sheet1
 
Upvote 0
Hi Sandy666, Do I need to instal an addon for that to work? Will that work on multiple entries? I have over 20,000 rows, some surnames have only one skill displayed and therefore only one row, others have all 8 skills and therefore 8 rows...
 
Upvote 0
Hi Peter_SSs, I'm not fussed where the results end up, either on a new sheet or overwrite the existing data, I have run your code, but it didn't do anything, do I need to highlight rows that I want to merge prior to running?
 
Last edited:
Upvote 0
Do I need to instal an addon for that to work? Will that work on multiple entries? I have over 20,000 rows, some surnames have only one skill displayed and therefore only one row, others have all 8 skills and therefore 8 rows...
You didn't show your excel version, so I don't know you will need add-in or you've PQ built-in.
It should work for all rows

all information should be in the first post with the representative example
 
Last edited:
Upvote 0
Hi Sandy, I cannot find the version info anywhere but I think I have found the Query section and so I will try your code later. Apologies for not knowing what I don't know (to put info in 1st post), not knowing was what brought me to the forum. I came for help, unfortunately i tried to use my phone in the first instance as I couldn't get on to a wifi on my laptop hence the terrible example given above.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,178
Members
453,021
Latest member
Justyna P

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top