Merge cells based on duplicate values in adjacent cells

sabrez

New Member
Joined
Oct 25, 2017
Messages
12
Hi

I have a table as below:

[TABLE="class: grid, width: 100"]
<tbody>[TR]
[TD]1[/TD]
[TD]$20[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]$20[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]$30[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]$15[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]$15[/TD]
[/TR]
</tbody>[/TABLE]

Now, I want to merge the cells in the 2nd column for corresponding duplicate values in col 1, as below:

[TABLE="class: grid, width: 100"]
<tbody>[TR]
[TD]1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]$20[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]$30[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]$15[/TD]
[/TR]
</tbody>[/TABLE]


Regards
Sabrez
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
Hi,



Ctrl+Shift+Enter NOT just Enter

E2=IFERROR(IFERROR(INDEX($B$2:$B$6, MATCH(0, COUNTIF($E$1:E1,$B$2:$B$6), 0)),INDEX($B$2:$B$6, MATCH(0, COUNTIF($E$1:E1,$B$2:$B$6),0))), "")

Just Enter

D2 =INDEX($A$2:$A$6,MATCH(E2,$B$2:$B$6,0))


[TABLE="width: 420"]
<colgroup><col width="70" span="6" style="width:52pt"> </colgroup><tbody>[TR]
[TD="class: xl63, width: 70"][/TD]
[TD="class: xl63, width: 70"]A[/TD]
[TD="class: xl63, width: 70"]B[/TD]
[TD="class: xl63, width: 70"]C[/TD]
[TD="class: xl63, width: 70"]D[/TD]
[TD="class: xl63, width: 70"]E[/TD]
[/TR]
[TR]
[TD="class: xl63"]1[/TD]
[TD="class: xl63"]1[/TD]
[TD="class: xl63"]$20[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]1[/TD]
[TD="class: xl63"]$20[/TD]
[/TR]
[TR]
[TD="class: xl63"]2[/TD]
[TD="class: xl63"]1[/TD]
[TD="class: xl63"]$20[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]2[/TD]
[TD="class: xl63"]$30[/TD]
[/TR]
[TR]
[TD="class: xl63"]3[/TD]
[TD="class: xl63"]2[/TD]
[TD="class: xl63"]$30[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"]3[/TD]
[TD="class: xl63"]$15[/TD]
[/TR]
[TR]
[TD="class: xl63"]4[/TD]
[TD="class: xl63"]3[/TD]
[TD="class: xl63"]$15[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"][/TD]
[/TR]
[TR]
[TD="class: xl63"]5[/TD]
[TD="class: xl63"]3[/TD]
[TD="class: xl63"]$15[/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"][/TD]
[TD="class: xl63"][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Hi sabrez,

from what I understand, you want to merge the cells in the second column based on common value in column 1. The code below assumes your data starts in A1 and doesn't matter if your data has headings or not.

Sub Macro1()

Dim lc As Integer
Dim x As Integer
Dim i As Integer
Dim d As Range

Application.DisplayAlerts = False

Set d = ThisWorkbook.Sheets(1).UsedRange
lc = d.Columns.Count

i = 1
For Each cell In d.Columns(1).Cells

If cell.Value = cell.Offset(1, 0).Value And x = 0 Then
x = cell.Row
i = i + 1

ElseIf Application.WorksheetFunction.CountIf(ThisWorkbook.Sheets(1).Range("A1:A" & i), cell.Value) <> 1 And cell.Value <> cell.Offset(1, 0).Value Then

Range(Cells(x, lc), cell.Offset(0, 1)).Select
Selection.Merge
x = 0
i = i + 1

Else

i = i + 1

End If

Next cell

Application.DisplayAlerts = True

End Sub
 
Upvote 0
Maybe this is better, assuming duplicated values is in column 1 and values to merge is in the column next to column 1.

Sub Macro1()

Dim lc As Integer
Dim x As Integer
Dim d As Range

Application.DisplayAlerts = False

Set d = ThisWorkbook.Sheets(1).UsedRange
lc = d.Columns.Count

For Each cell In d.Columns(1).Cells

If cell.Value = cell.Offset(1, 0).Value And x = 0 Then
x = cell.Row

ElseIf Application.WorksheetFunction.CountIf(d.Columns(1), cell.Value) <> 1 And cell.Value <> cell.Offset(1, 0).Value Then

Range(cell.Offset(-(cell.Row - x), 1), cell.Offset(0, 1)).Select
Selection.Merge
x = 0

End If

Next cell

Application.DisplayAlerts = True

End Sub
 
Upvote 0
Maybe this is better, assuming duplicated values is in column 1 and values to merge is in the column next to column 1.

Sub Macro1()

Dim lc As Integer
Dim x As Integer
Dim d As Range

Application.DisplayAlerts = False

Set d = ThisWorkbook.Sheets(1).UsedRange
lc = d.Columns.Count

For Each cell In d.Columns(1).Cells

If cell.Value = cell.Offset(1, 0).Value And x = 0 Then
x = cell.Row

ElseIf Application.WorksheetFunction.CountIf(d.Columns(1), cell.Value) <> 1 And cell.Value <> cell.Offset(1, 0).Value Then

Range(cell.Offset(-(cell.Row - x), 1), cell.Offset(0, 1)).Select
Selection.Merge
x = 0

End If

Next cell

Application.DisplayAlerts = True

End Sub


Perfect!! This is exactly what I wanted. Thanks a ton

Regards
Sabrez
 
Upvote 0

Forum statistics

Threads
1,223,246
Messages
6,170,996
Members
452,373
Latest member
TimReeks

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