CONCATENATE function

shuklaankur281190

Board Regular
Joined
Sep 30, 2014
Messages
61
Hi All,

There is a problem i am facing with CONCATENATE function. Here is in below table.

[TABLE="width: 128"]
<colgroup><col style="width:48pt" span="2" width="64"> </colgroup><tbody>[TR]
[TD="width: 64"]Harry[/TD]
[TD="width: 64"]AC[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]DA[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]PC[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]KA[/TD]
[/TR]
[TR]
[TD]Stu[/TD]
[TD]DA[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]KA[/TD]
[/TR]
[TR]
[TD]Neena[/TD]
[TD]PC[/TD]
[/TR]
[TR]
[TD]Pihu[/TD]
[TD]KA[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]NA[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]RE[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]PK[/TD]
[/TR]
[TR]
[TD]Kenny[/TD]
[TD]NE[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]RA[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]TE[/TD]
[/TR]
</tbody>[/TABLE]

I wanna add add name and his character showing in front of till second name in C column.

Please help me
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
Thanks AhoyNC,this is awesome but in this trick i can concatenate only two column but i need to put together first column with second column till next first column has next text.
[h=3][/h]
 
Upvote 0
Your question is not entirely clear, but let me take a guess at what you want. Assuming "Harry" and "AC" are in Row 1, put this formula in cell C1 and copy it down...

=LOOKUP("zzzzzzz",A$1:A1,A:A)&" "&B1
 
Upvote 0
Oh Thanks Mr.rick,,, you formula works perfectly. but i need table a below.

[TABLE="width: 798"]
<colgroup><col style="width:86pt" span="7" width="114"> </colgroup><tbody>[TR]
[TD="width: 114"]A[/TD]
[TD="width: 114"][/TD]
[TD="width: 114"]B[/TD]
[TD="width: 114"][/TD]
[TD="width: 114"]C[/TD]
[TD="width: 114"][/TD]
[TD="width: 114"]D[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]With you farmula[/TD]
[TD][/TD]
[TD]Need like[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"]Harry[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]AC[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Harry AC[/TD]
[TD][/TD]
[TD]Harry AC,DA,PC,KA[/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]DA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Harry DA[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]PC[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Harry PC[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]KA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Harry KA[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"]Stu[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]DA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Stu DA[/TD]
[TD][/TD]
[TD]Stu DA,KA[/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]KA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Stu KA[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"]Neena[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]PC[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Neena PC[/TD]
[TD][/TD]
[TD]Neena PC[/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"]Pihu[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]KA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Pihu KA[/TD]
[TD][/TD]
[TD]Pihu KA,NA,RE,PK[/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]NA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Pihu NA[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]RE[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Pihu RE[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]PK[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Pihu PK[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"]Kenny[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]NE[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Kenny NE[/TD]
[TD][/TD]
[TD]Kenny NE,RA,TE[/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]RA[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Kenny RA[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"][/TD]
[TD="class: xl65, width: 114"]TE[/TD]
[TD="class: xl65, width: 114"][/TD]
[TD]Kenny TE[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
You are going to need a macro in order to do that...

Code:
Sub NameAndCharacters()
  Dim X As Long, Rws As Variant, Cell As Range, Nmes As Range
  Set Nmes = Range("A1:A" & Cells(Rows.Count, "B").End(xlUp).Row).SpecialCells(xlConstants)
  ReDim Rws(1 To Nmes.Count + 1)
  For Each Cell In Nmes
    X = X + 1
    Rws(X) = Cell.Row
  Next
  Rws(UBound(Rws)) = Cells(Rows.Count, "B").End(xlUp).Row + 1
  For X = LBound(Rws) To UBound(Rws) - 1
    If Rws(X + 1) - Rws(X) = 1 Then
      Cells(Rws(X), "C") = Cells(Rws(X), "A") & " " & Cells(Rws(X), "B")
    Else
      Cells(Rws(X), "C") = Cells(Rws(X), "A") & " " & Join(Application.Transpose( _
                           Cells(Rws(X), "B").Resize(Rws(X + 1) - Rws(X))), ",")
    End If
  Next
End Sub


HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (NameAndCharacters) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.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.
 
Upvote 0
Mr.Rick you did a awesome trick but if i don't know Macros then it will not easy with formula ?
Because of the variability of rows between names, there can be no direct formula solution (Excel's text handling with formulas is somewhat limited and inflexible). There may be a formula type solution, but I think it would involve hand-crafted manual dragging of intermediary formulas coupled with multiple helper cells.
 
Upvote 0
have been playing with this for couple of hour this formula seems to work upto a limit of four instances of column B

it can be extended to include more but my coffee ran out

so stopped at your data sample

Code:
=IF(A2<>"",IF(A3<>"",CONCATENATE(A2," ",B2),IF(A4<>"",CONCATENATE(A2," ",B2," ",B3),IF(A5<>"",CONCATENATE(A2," ",B2," ",B3," ",B4),IF(A6<>"",CONCATENATE(A2," ",B2," ",B3," ",B4," ",B5),CONCATENATE(A2," ",B2))))),"")

[TABLE="width: 322"]
<tbody>[TR]
[TD]Harry[/TD]
[TD]AC[/TD]
[TD]Harry AC DA PC KA[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]DA[/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD]PC[/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD]KA[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Stu[/TD]
[TD]DA[/TD]
[TD]Stu DA KA[/TD]
[/TR]
</tbody>[/TABLE]

with my formula in C2 copied down
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,874
Members
452,363
Latest member
merico17

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