Concatnate 6 rows data in 1 cell

exceluser9

Active Member
Joined
Jun 27, 2015
Messages
388
Hi There,

I have a data like this in both sheet.

i Want to put a lookup for 2005 in second sheet and get 1;2;3;4;5;6 in column B in sheet 1. How do i do that?
Sheet 1Sheet 2
COLUMN ACOLUMN BCOLUMN NCOLUMN AX
20051;2;3;4;5;620051
20052
20053
20054
20055
20056

<tbody>
</tbody><colgroup><col><col><col span="2"><col><col></colgroup>



<tbody>
</tbody><colgroup><col><col><col span="2"><col><col></colgroup>
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
pintog1989,

1. What version of Excel, and, Windows are you using?

2. Are you using a PC or a Mac?

Here is a macro solution for you to consider, based on the assumption that Sheet1, and, Sheet2, have titles in row 1.

If they do not have titles in row 1, then I will have to re-write the macro.

Sample worksheet before the macro:


Excel 2007
NAX
1Title NTitle AX
220051
320052
420053
520054
620055
720056
8200611
9
10200612
11
12200613
13
14200614
15
Sheet2



Excel 2007
AB
1Tile ATitle B
22005
32006
4
Sheet1


After the macro:


Excel 2007
AB
1Tile ATitle B
220051;2;3;4;5;6
3200611;12;13;14
4
Sheet1


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub pintog1989()
' hiker95, 07/05/2015, ME865681
Dim w1 As Worksheet, w2 As Worksheet
Dim c As Range, nx As Range, n As Long, i As Long, t As String
Dim lr As Long, sr As Long
Application.ScreenUpdating = False
Set w1 = Sheets("Sheet1")
Set w2 = Sheets("Sheet2")
lr = w2.Cells(Rows.Count, 50).End(xlUp).Row
With w1
  For Each c In .Range("A2", .Range("A" & Rows.Count).End(xlUp))
    n = Application.CountIf(w2.Columns(14), c.Value)
    If n > 0 Then
      t = "": sr = 1
      For i = 1 To n
        Set nx = w2.Range("N" & sr & ":N" & lr).Find(c.Value, LookAt:=xlWhole)
        If Not nx Is Nothing Then
          t = t & w2.Cells(nx.Row, 50).Value & ";"
          sr = nx.Row
        End If
      Next i
      If Right(t, 1) = ";" Then
        c.Offset(, 1).Value = Left(t, Len(t) - 1)
        t = "": sr = 1
      End If
    End If
  Next c
  .Columns(2).AutoFit
End With
Application.ScreenUpdating = False
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the pintog1989 macro.
 
Last edited:
Upvote 0
Assuming the values in Column N on Sheet2 are constants (that is, there are no formulas in the column), then here is another macro you can consider...
Code:
[SIZE=1]Sub pintog1989Too()
  Dim R As Long, S1 As Worksheet, S2 As Worksheet
  Set S1 = Sheets("Sheet1")
  Set S2 = Sheets("Sheet2")
  For R = 2 To S1.Cells(Rows.Count, "A").End(xlUp).Row
    If Application.CountIf(S2.Columns("N"), S1.Cells(R, "A").Value) Then
      S2.Columns("N").Replace S1.Cells(R, "A").Value, "=" & S1.Cells(R, "A").Value, xlWhole
      Intersect(S2.Columns("N").SpecialCells(xlFormulas).EntireRow, S2.Columns("AX")).Copy S1.Cells(R, "B")
      S1.Cells(R, "B") = Replace(Trim(Join(Application.Transpose(Range(S1.Cells(R, "B"), _
                         S1.Cells(Rows.Count, "B").End(xlUp).Offset(1))), " ")), " ", ";")
      S1.Cells(R, "B").Offset(1).Resize(Rows.Count - R).Clear
      S2.Columns("N").Replace "=", "", xlPart
    End If
  Next
End Sub[/SIZE]
 
Upvote 0

Forum statistics

Threads
1,214,653
Messages
6,120,756
Members
448,990
Latest member
Buzzlightyear

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