Concatenate Without Duplicates

bigdaddy123

New Member
Joined
Aug 6, 2012
Messages
7
My spreadsheet has 32 columns each with a city name in it, though some cells may be blank in the latter columns. Column A, B, and C may have the same city multiple times. I need to Concatenate this information into a single cell such as "New York, Philadelphia, Chicago, Atlanta," etc, without any duplicates. Of course, omitting any blank cells would be great, but not a must.

I have seen a few "VBA modules" on the web, but will admit my ignorance. I have never used one, so, if you are providing one, would you be so kind to go through the steps to implement this?

Thanks!
 
Thank you for the quick response. Here is the Data

[TABLE="width: 750"]
<colgroup><col><col><col><col><col></colgroup><tbody>[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]MOUNTAIN MAX 800[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4 800[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VX800AQA[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]MOUNTAIN MAX 800 ST[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4 800[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4 800[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4 ST[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4 ST[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4 750[/TD]
[/TR]
[TR]
[TD]138-5232U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]VMAX-4[/TD]
[/TR]
[TR]
[TD]140-4352U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]GSX SPORT 500SS[/TD]
[/TR]
[TR]
[TD]140-4352U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]GTX SPORT 500 SS[/TD]
[/TR]
[TR]
[TD]140-4352U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]MX Z TNT 500SS (2)[/TD]
[/TR]
[TR]
[TD]140-4352U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]MX Z TRAIL 500 S.S.[/TD]
[/TR]
[TR]
[TD]140-4352U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]GSX SPORT 500SS[/TD]
[/TR]
</tbody>[/TABLE]

Here is the result I need

140-4352U4
MakeSki-DooModelGSX SPORT 500SS, GTX SPORT 500 SS, MX Z TNT 500SS (2), MX Z TRAIL 500 S.S.

<colgroup><col style="mso-width-source:userset;mso-width-alt:4717;width:97pt" width="129"> <col style="mso-width-source:userset;mso-width-alt:5558;width:114pt" width="152"> <col style="mso-width-source:userset;mso-width-alt:5339;width:110pt" width="146"> <col style="mso-width-source:userset;mso-width-alt:2157;width:44pt" width="59"> <col style="mso-width-source:userset;mso-width-alt:4205;width:86pt" width="115"> </colgroup><tbody>
[TD="width: 129"]138-5232U4
[/TD]
[TD="width: 152"]Make
[/TD]
[TD="width: 146"]Yamaha[/TD]
[TD="width: 59"]Model[/TD]
[TD="width: 115"]FORMULA III 600, MOUNTAIN MAX 800, VMAX-4 800, VX800AQA, MOUNTAIN MAX 800 ST, VMAX-4 ST, VMAX-4 750, VMAX-4
[/TD]

</tbody>
 
Upvote 0

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
See if this is any use.
Code:
Sub CombineData()
  Dim d As Object
  Dim a As Variant, b As Variant, itm As Variant
  Dim i As Long
  Dim s As String
  
  Set d = CreateObject("Scripting.Dictionary")
  d.CompareMode = 1
  a = Range("A2", Range("E" & Rows.Count).End(xlUp)).Value
  ReDim b(1 To UBound(a), 1 To 5)
  For i = 1 To UBound(a)
    s = Join(Application.Index(a, i, Array(1, 2, 3, 4)), ";")
    If Not d.exists(s) Then
      Set d(s) = CreateObject("Scripting.Dictionary")
    End If
    d(s)(a(i, 5)) = 1
  Next i
  Application.ScreenUpdating = False
  With Range("H2").Resize(d.Count)
    .Value = Application.Transpose(d.Keys())
    .TextToColumns DataType:=xlDelimited, Tab:=False, Semicolon:=True, Space:=False, Other:=False
    With .Offset(, 4)
      i = 0
      For Each itm In d.Items()
        i = i + 1
        .Cells(i).Value = Join(itm.Keys(), ", ")
      Next itm
    End With
    .Resize(, 5).EntireColumn.AutoFit
  Application.ScreenUpdating = True
  End With

My sample data in columns A:E, results of code in columns H:L

Excel Workbook
ABCDEFGHIJKL
1
2138-5232U4MakeYamahaModelMOUNTAIN MAX 800138-5232U4MakeYamahaModelMOUNTAIN MAX 800, VMAX-4 800, VX800AQA, MOUNTAIN MAX 800 ST, VMAX-4 ST, VMAX-4 750, VMAX-4
3138-5232U4MakeYamahaModelVMAX-4 800140-4352U4MakeSki-DooModelGSX SPORT 500SS, GTX SPORT 500 SS, MX Z TNT 500SS (2), MX Z TRAIL 500 S.S.
4138-5232U4MakeYamahaModelVX800AQA
5138-5232U4MakeYamahaModelMOUNTAIN MAX 800 ST
6138-5232U4MakeYamahaModelVMAX-4 800
7138-5232U4MakeYamahaModelVMAX-4 800
8138-5232U4MakeYamahaModelVMAX-4 ST
9138-5232U4MakeYamahaModelVMAX-4 ST
10138-5232U4MakeYamahaModelVMAX-4 750
11138-5232U4MakeYamahaModelVMAX-4
12140-4352U4MakeSki-DooModelGSX SPORT 500SS
13140-4352U4MakeSki-DooModelGTX SPORT 500 SS
14140-4352U4MakeSki-DooModelMX Z TNT 500SS (2)
15140-4352U4MakeSki-DooModelMX Z TRAIL 500 S.S.
16140-4352U4MakeSki-DooModelGSX SPORT 500SS
Sheet1
 
Upvote 0
Thank you Peter, how would I expand this to more columns. For example there is a column for year and engine size as well. Secodnly how to I apply this to the sheet.
 
Upvote 0
Thank you Peter, how would I expand this to more columns. For example there is a column for year and engine size as well.
Code:
Sub CombineData()
  Dim d As Object
  Dim a As Variant, b As Variant, itm As Variant
  Dim i As Long
  Dim s As String
  
  Set d = CreateObject("Scripting.Dictionary")
  d.CompareMode = 1
  a = Range("A2", Range("[COLOR="#FF0000"][B]E[/B][/COLOR]" & Rows.Count).End(xlUp)).Value [COLOR="#008000"][B]'<- This is the last column of your data[/B][/COLOR]
  ReDim b(1 To UBound(a), 1 To [COLOR="#FF0000"][B]5[/B][/COLOR]) [COLOR="#008000"][B]'<- This is the number of columns in your data[/B][/COLOR]
  For i = 1 To UBound(a)
    s = Join(Application.Index(a, i, Array([COLOR="#FF0000"][B]1, 2, 3, 4[/B][/COLOR])), ";") [COLOR="#008000"][B]'<- These are the columns that do not get concatenated[/B][/COLOR]
    If Not d.exists(s) Then
      Set d(s) = CreateObject("Scripting.Dictionary")
    End If
    d(s)(a(i, [COLOR="#FF0000"][B]5[/B][/COLOR])) = 1 [COLOR="#008000"][B]'<- This is the number of columns in your data[/B][/COLOR]
  Next i
  Application.ScreenUpdating = False
  With Range("[COLOR="#FF0000"][B]H2[/B][/COLOR]").Resize(d.Count)  [COLOR="#008000"][B]'<- This is the top left cell where you want the results[/B][/COLOR]
    .Value = Application.Transpose(d.Keys())
    .TextToColumns DataType:=xlDelimited, Tab:=False, Semicolon:=True, Space:=False, Other:=False
    With .Offset(, [COLOR="#FF0000"][B]4[/B][/COLOR]) [COLOR="#008000"][B]'<- This is the number of columns that do not get concatenated[/B][/COLOR]
      i = 0
      For Each itm In d.Items()
        i = i + 1
        .Cells(i).Value = Join(itm.Keys(), ", ")
      Next itm
    End With
    .Resize(, [COLOR="#FF0000"][B]5[/B][/COLOR]).EntireColumn.AutoFit [COLOR="#008000"][B]'<- This is the number of columns in your data[/B][/COLOR]
  Application.ScreenUpdating = True
  End With
End Sub


Secodnly how to I apply this to the sheet.
Do you mean how do you run the code? If so, there are several ways, but note my code is not a function to be used like some of the earlier codes in the thread. To get the code in place ..
1. With your workbook active press Alt+F11 to bring up the vba window.
2. In the Visual Basic window use the menu to Insert|Module
3. Copy and Paste the code into the main right hand pane that opens at step 2.
4. Close the Visual Basic window.
5. Your workbook will need to be saved as a macro-enabled workbook (*.xlsm)

To actually run the code ..
a) Press Alt+F8 to bring up the Macro dialog, Select the macro & click ‘Run’, or
b) You can insert a button or shape on your sheet, attach the macro to that & then you can just click the button, or
c) The macro can be added to the Quick Access Toolbar.
etc.
 
Upvote 0
Thank you Peter. I have modified the code based on your comments, but regardless what I do it only concatenates 1 column. Below are the changes I made.
Code:
Sub CombineData()
  Dim d As Object
  Dim a As Variant, b As Variant, itm As Variant
  Dim i As Long
  Dim s As String
  
  Set d = CreateObject("Scripting.Dictionary")
  d.CompareMode = 1
  a = Range("A2", Range("K" & Rows.Count).End(xlUp)).Value '<- This is the last column of your data
  ReDim b(1 To UBound(a), 1 To 11) '<- This is the number of columns in your data
  For i = 1 To UBound(a)
    s = Join(Application.Index(a, i, Array(1, 2, 3, 4, 6, 8, 10)), ";") '<- These are the columns that do not get concatenated
    If Not d.exists(s) Then
      Set d(s) = CreateObject("Scripting.Dictionary")
    End If
    d(s)(a(i, 11)) = 1 '<- This is the number of columns in your data
  Next i
  Application.ScreenUpdating = False
  With Range("P2").Resize(d.Count)  '<- This is the top left cell where you want the results
    .Value = Application.Transpose(d.Keys())
    .TextToColumns DataType:=xlDelimited, Tab:=False, Semicolon:=True, Space:=False, Other:=False
    With .Offset(, 7) '<- This is the number of columns that do not get concatenated
      i = 0
      For Each itm In d.Items()
        i = i + 1
        .Cells(i).Value = Join(itm.Keys(), ", ")
      Next itm
    End With
    .Resize(, 11).EntireColumn.AutoFit '<- This is the number of columns in your data
  Application.ScreenUpdating = True
  End With
End Sub
 
Last edited by a moderator:
Upvote 0
Thank you Peter. I have modified the code based on your comments, but regardless what I do it only concatenates 1 column.
You didn't ever say there was to be more than one column concatenated, you just said there were more columns. Remember, we only know what you tell us clearly and/or show us.
Please provide another small set of representative sample data and the corresponding results.
 
Upvote 0
Sorry Peter. My mistake. Here is a sample of all columns.

[TABLE="width: 1416"]
<colgroup><col><col><col><col><col><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]SKU[/TD]
[TD]Attribute 2 Name [/TD]
[TD]Attribute 2 Value(s)[/TD]
[TD]Attribute 3 Name[/TD]
[TD]Attribute 3 Value(s)[/TD]
[TD]Attribute 6 Name[/TD]
[TD]Attribute 6 Value(s)[/TD]
[TD]Attribute 7 Name[/TD]
[TD]Attribute 7 Value(s)[/TD]
[TD]Attribute 1 Name[/TD]
[TD]Attribute 1 value(s)[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY [/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2018[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY ADVENTURE [/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2018[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY / INTL[/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2018[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY LXT [/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2018[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY VOYAGEUR [/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2018[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY [/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2017[/TD]
[/TR]
[TR]
[TD]125-4240U4[/TD]
[TD]Make[/TD]
[TD]Polaris[/TD]
[TD]Model[/TD]
[TD]550 INDY ADVENTURE (144)[/TD]
[TD]CC[/TD]
[TD="align: right"]544[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]3211154[/TD]
[TD]YR[/TD]
[TD="align: right"]2017[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
And what about the following so we have some idea of what has to be concatenated and what does not?


Also, is that data representative? Many of the columns are filled with identical data.

Columns E,G,I,K all need to be concatenated. Here is another example to show you how the data changes.

[TABLE="width: 1480"]
<colgroup><col><col><col><col><col><col><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]125-4320U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]SR540D[/TD]
[TD]CC[/TD]
[TD="align: right"]540[/TD]
[TD]Mfg. Belt #[/TD]
[TD]8F2-17641-01-00[/TD]
[TD]YR[/TD]
[TD="align: right"]1980[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]125-4320U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]EC540C [/TD]
[TD]CC[/TD]
[TD="align: right"]540[/TD]
[TD]Mfg. Belt #[/TD]
[TD]8F2-17641-01-00[/TD]
[TD]YR[/TD]
[TD="align: right"]1979[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]125-4320U4[/TD]
[TD]Make[/TD]
[TD]Yamaha[/TD]
[TD]Model[/TD]
[TD]EC540C [/TD]
[TD]CC[/TD]
[TD="align: right"]540[/TD]
[TD]Mfg. Belt #[/TD]
[TD]8F2-17641-01-00[/TD]
[TD]YR[/TD]
[TD="align: right"]1979[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]131-4126U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]FREESTYLE 300F[/TD]
[TD]CC[/TD]
[TD="align: right"]300[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]417300298[/TD]
[TD]YR[/TD]
[TD="align: right"]2006[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]131-4400U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]SAFARI CHEYENNE[/TD]
[TD]CC[/TD]
[TD="align: right"]496[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]414375800[/TD]
[TD]YR[/TD]
[TD="align: right"]1989[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]131-4400U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]ALPINE[/TD]
[TD]CC[/TD]
[TD="align: right"]496[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]414523300[/TD]
[TD]YR[/TD]
[TD="align: right"]1987[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]131-4400U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]ALPINE[/TD]
[TD]CC[/TD]
[TD="align: right"]496[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]414375800[/TD]
[TD]YR[/TD]
[TD="align: right"]1986[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]131-4400U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]ALPINE[/TD]
[TD]CC[/TD]
[TD="align: right"]496[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]414375800[/TD]
[TD]YR[/TD]
[TD="align: right"]1985[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]131-4400U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]ALPINE[/TD]
[TD]CC[/TD]
[TD="align: right"]497[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]4143758[/TD]
[TD]YR[/TD]
[TD="align: right"]1983[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

And the result should look like this

[TABLE="width: 2250"]
<colgroup><col><col span="16"><col><col><col span="3"><col></colgroup><tbody>[TR]
[TD]138-4332U4[/TD]
[TD]Make[/TD]
[TD]Arctic Cat[/TD]
[TD]Model[/TD]
[TD]LYNX[/TD]
[TD]CC[/TD]
[TD="align: right"]339[/TD]
[TD]Mfg. Belt #[/TD]
[TD]0227-030[/TD]
[TD]YR[/TD]
[TD="align: right"]1993[/TD]
[TD][/TD]
[TD]Make[/TD]
[TD]Arctic Cat, Ski-Doo[/TD]
[TD]Model[/TD]
[TD]LYNX, LYNX DELUXE, LYNX 300, LYNX 300 DELUXE, JAG AFS, PANTHER, SUPER JAG, COUGAR, EL TIGRÉ5000, PANTERA, PANTHER 5000, Skandic 550F, Skandic WT 550 Fan, Tundra WT 550 Fan, Skandic SWT 550, Tundra WT 550 RER Europe, Skandic WT 500, Tundra WT 550 RER, Expedition Sport 550F XP, GRAND TOURING SPORT 550F XP, MXZ SPORT 550F XP, RENEGADE SPORT 550F XP, Skandic WT 550F XU, Skandic SWT 550F XU, TUNDRA LT 550F XP, TUNDRA WT 550F RER XU, TUNDRA SPORT 550F XP, MX Z SPORT 550F XP, RENEGADE SPORT 550F XP, SKANDIC WT 550F, TUNDRA SPORT 550F , Expedition Sport 550F XP-FAN, GRAND TOURING SPORT 550F XP-FAN, MX Z TNT 550F XP-FAN, MX Z SPORT 550F XP-FAN, RENEGADE SPORT 550F XP-FAN, SKANDIC WT 600 ACE (Europe), TUNDRA STD 550F XP, EXPEDITION SPORT 600 ACE, GRAND TOURING SPORT 600, GRAND TOURING SPORT 600 ACE, MX Z TNT (XP) ACE, RENEGADE SPORT 600 ACE, SKANDIC TUNDRA LT 600 ACE, SKANDIC WT (XU) 600 ACE, FREESTYLE BACKCOUNTRY 550F, GSX FAN 550, GTX FAN, MX Z 550F X, SKANDIC TUNDRA LT 550F, SUMMIT EVEREST FAN 550, EXPEDITION SPORT 550 FAN, FREESTYLE PARK 550F, GSX 550 Fan, GTX 550 FAN, MX Z 550 Fan, MX Z 550 X, SUMMIT 550 Fan, EXPEDITION SPORT , FREESTYLE BACK COUNTRY, FREESTYLE PARK, FREESTYLE SESSION, GSX FAN, MX Z FAN, SUMMIT FAN 550, EXPEDITION SPORT 550F, GSX FAN 380F, GSX FAN 550F, GTX FAN 380F, GTX FAN 550F, MX Z 380F, MX Z 550F, SUMMIT FAN 550F, GSX FAN 380, MX Z FAN 380F, MX Z FAN 550F, LEGEND FAN 380, LEGEND FAN 550, LEGEND FAN GT 380, LEGEND FAN GT 550, LEGEND GT SE 600 H.O.SDI, LEGEND SPORT 500 SS, LEGEND SPORT GT 500 SS, MX Z 380 FAN, MX Z 550 FAN, SUMMIT 550 FAN, GRAND TOURING 550 FAN, GRAND TOURING 550 FAN RER, GRAND TOURING FAN, GRAND TOURING 380 FAN RER, GRAND TOURING SE 600 RER, GRAND TOURING SPORT 500 RER, GRAND TOURING SPORT 600 RER, LEGEND 380 FAN RER, LEGEND 380 FAN, LEGEND 550 FAN, LEGEND 550 FAN RER , LEGEND SE 600 RER, LEGEND SPORT 600 RER, LEGEND SPORT 500 RER, MX Z ADRENALINE 500 RER, MX Z 550 FAN RER, MX Z 380 FAN RER, MX Z TRAIL 500, MX-Z TRAIL 600 RER, MX Z TRAIL 500 RER, MX Z TRAIL 600, MX Z X 440 RACING, SKANDIC SPORT 500F, SKANDIC SPORT 500F RER, SKANDIC TUNDRA 280F RER, SKANDIC TUNDRA 280 F, SUMMIT 550 F, GRAND TOURING 380F, GRAND TOURING 500F, GRAND TOURING GS, GRAND TOURING SE, GRAND TOURING SPORT, LEGEND FAN 500F, LEGEND FAN 380F, LEGEND GS, LEGEND SE, LEGEND SPORT, MX Z ADRENALINE 600 RER, MX Z 500 FAN, MX Z SPORT 600/600 RER, MX Z SPORT 500/500 RER, MX Z TRAIL, MX Z X, SUMMIT 500 FAN, FORMULA DELUXE FAN, FORMULA DELUXE GSE, FORMULA DELUXE STANDARD, GRAND TOURING STANDARD, MX Z ADRENALINE, MX Z STANDARD 600, MX Z STANDARD 500, SUMMIT FAN, TOURING FAN, FORMULA 500 LC, FORMULA DELUXE 380, FORMULA DELUXE 500, FORMULA DELUXE 500 LC, FORMULA DELUXE 600, FORMULA S, FORMULA Z 600, GRAND TOURING 600, MX Z 440, MX Z 500, MX Z 600, MX ZX 440 LC, SKANDIC 380, SKANDIC 500, SUMMIT 500, SUMMIT 600, TOURING 500 LC, TOURING E, TOURING LE, TOURING SLE, FORMULA DELUXE 583, FORMULA SL, FORMULA Z 500, FORMULA Z 583, GRAND TOURING 500, GRAND TOURING 583, FORMULA 500, FORMULA 500 DELUXE, FORMULA 583 DELUXE, FORMULA S E, MX Z 583, FORMULA 583, FORMULA Z, MX Z 440 FC, TOURING E LT 2-UP, FORMULA SLS, FORMULA STX, FORMULA STX LT, GRAND TOURING 580, MX Z, SUMMIT 583, FORMULA LT, FORMULA ST[/TD]
[TD]CC[/TD]
[TD]339, 431, 500, 436, 550, 849, 600, 553, 380, 368, 594, 497, 380F, 440, 280, 499, 597, 437, 581, 699, 449, 496, 580, 462[/TD]
[TD]Mfg. Belt #[/TD]
[TD]0227-030, 414860700, 415060600, 417300064[/TD]
[TD]YR[/TD]
[TD="colspan: 2"]1993, 1992, 1991, 1989, 1988, 1987, 1986, 1985, 1984, 1981, 2018, 2017, 2016, 2015, 2014, 2013, 2012, 2011, 2009, 2008, 2007, 2006, 2005, 2004, 2003, 2002, 2001, 2000, 1999, 1998, 1997, 1996, 1995, 1994[/TD]
[/TR]
[TR]
[TD]138-4340U4[/TD]
[TD]Make[/TD]
[TD]Arctic Cat[/TD]
[TD]Model[/TD]
[TD]CHEETAH 550[/TD]
[TD]CC[/TD]
[TD="align: right"]550[/TD]
[TD]Mfg. Belt #[/TD]
[TD]0227-103[/TD]
[TD]YR[/TD]
[TD="align: right"]1994[/TD]
[TD][/TD]
[TD]Make[/TD]
[TD]Arctic Cat[/TD]
[TD]Model[/TD]
[TD]CHEETAH 550, PANTERA, EXT 580Z, EXT EFI, EXT MOUNTAIN CAT, EXT, EXT SPECIAL, WILDCAT 700 EFI, WILDCAT 700 MOUNTAIN CAT, EL TIGRÉEXT, EL TIGRÉMOUNTAIN CAT, WILDCAT 700, COUGAR, WILDCAT 650, WILDCAT, EL TIGRÉ5000, CHEETAH, EL TIGRÉ6000, PANTHER, EL TIGRE[/TD]
[TD]CC[/TD]
[TD]550, 580, 700, 529, 500, 650, 500-529[/TD]
[TD]Mfg. Belt #[/TD]
[TD]0227-103, 0627-006, 0627-001, 0627-004, 0227-032[/TD]
[TD]YR[/TD]
[TD="colspan: 2"]1994, 1993, 1992, 1991, 1990, 1989, 1988, 1987, 1986, 1985, 1984, 1981[/TD]
[/TR]
[TR]
[TD]138-4353U4[/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]FORMULA III[/TD]
[TD]CC[/TD]
[TD="align: right"]598[/TD]
[TD]Mfg. Belt #[/TD]
[TD="align: right"]4.15E+08[/TD]
[TD]YR[/TD]
[TD="align: right"]1997[/TD]
[TD][/TD]
[TD]Make[/TD]
[TD]Ski-Doo[/TD]
[TD]Model[/TD]
[TD]FORMULA III, MACH I, MX Z 670, SUMMIT 583, SUMMIT 670, FORMULA SS, GRAND TOURING SE, GRAND TOURING SE 670[/TD]
[TD]CC[/TD]
[TD]598, 699, 669, 581[/TD]
[TD]Mfg. Belt #[/TD]
[TD]415060300, 414918200[/TD]
[TD]YR[/TD]
[TD="colspan: 2"]1997, 1996, 1995[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Okay, that is a bit of a different kettle of fish, but give this a try.
Rich (BB code):
Sub CombineData_v2()
  Dim d As Object
  Dim a As Variant, b As Variant, itm As Variant, ConcatCols As Variant, NonConcatCols As Variant
  Dim i As Long, j As Long, k As Long, r As Long, ubCC As Long, ubNCC As Long, ubb As Long
  Dim s As String
  
  Set d = CreateObject("Scripting.Dictionary")
  d.CompareMode = 1
  ConcatCols = Split("5 7 9 11")  '<- Columns that get concatenated
  ubCC = UBound(ConcatCols)
  NonConcatCols = Split("1 2 3 4 6 8 10") '<- Columns that don't get concatenated
  ubNCC = UBound(NonConcatCols)
  a = Range("A2", Range("K" & Rows.Count).End(xlUp)).Value '<- Where the data is
  ReDim b(1 To UBound(a), 1 To UBound(a, 2))
  ubb = UBound(b, 2)
  For i = 1 To UBound(a)
    s = a(i, 1)
    If Not d.exists(s) Then
      k = k + 1
      d(s) = k
      For j = 1 To ubb
        b(k, j) = a(i, j)
      Next j
    Else
      r = d(s)
      For j = 0 To ubCC
        b(r, ConcatCols(j)) = b(r, ConcatCols(j)) & "," & a(i, ConcatCols(j))
      Next j
    End If
  Next i
  For i = 1 To k
    For j = 0 To ubCC
      d.RemoveAll
      For Each itm In Split(b(i, ConcatCols(j)), ",")
        d(itm) = 1
      Next itm
      b(i, ConcatCols(j)) = Join(d.Keys(), ", ")
    Next j
  Next i
  Range("M2").Resize(k, ubb).Value = b '<- Top left of results
End Sub

Sample data from post 29 and code results starting in column M.


Book1
ABCDEFGHIJKLMNOPQRSTUVW
2125-4320U4MakeYamahaModelSR540DCC540Mfg. Belt #8F2-17641-01-00YR1980125-4320U4MakeYamahaModelSR540D, EC540CCC540Mfg. Belt #8F2-17641-01-00YR1980, 1979
3125-4320U4MakeYamahaModelEC540CCC540Mfg. Belt #8F2-17641-01-00YR1979131-4126U4MakeSki-DooModelFREESTYLE 300FCC300Mfg. Belt #417300298YR2006
4125-4320U4MakeYamahaModelEC540CCC540Mfg. Belt #8F2-17641-01-00YR1979131-4400U4MakeSki-DooModelSAFARI CHEYENNE, ALPINECC496, 497Mfg. Belt #414375800, 414523300, 4143758YR1989, 1987, 1986, 1985, 1983
5131-4126U4MakeSki-DooModelFREESTYLE 300FCC300Mfg. Belt #417300298YR2006
6131-4400U4MakeSki-DooModelSAFARI CHEYENNECC496Mfg. Belt #414375800YR1989
7131-4400U4MakeSki-DooModelALPINECC496Mfg. Belt #414523300YR1987
8131-4400U4MakeSki-DooModelALPINECC496Mfg. Belt #414375800YR1986
9131-4400U4MakeSki-DooModelALPINECC496Mfg. Belt #414375800YR1985
10131-4400U4MakeSki-DooModelALPINECC497Mfg. Belt #4143758YR1983
Sheet3
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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