Join multiple text from 2 columns

jjokol

Board Regular
Joined
Dec 21, 2008
Messages
213
Easiest way to explain what i want to do is:

Column A's values are A, B, C
Column B's values are X, Y Z

What macro can I use to combine all the values so that Column C's values are: AX, AY, AZ, BX, BY, BZ, CX, CY, CZ ?

Actually, as the values are words in real life, it would be great to have spaces between each one.
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
May this (array formula - use Ctrl+Shift+Enter and not only Enter):

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: center;;">A</td><td style="text-align: center;;">X</td><td style="text-align: center;;">A X</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;;">B</td><td style="text-align: center;;">Y</td><td style="text-align: center;;">A Y</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;;">C</td><td style="text-align: center;;">Z</td><td style="text-align: center;;">A Z</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">B X</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">B Y</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">B Z</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">C X</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">C Y</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;">C Z</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet8</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C1</th><td style="text-align:left">{=INDEX(<font color="Blue">TRANSPOSE(<font color="Red">A$1:A$3</font>)&" "&B$1:B$3,1+MOD(<font color="Red">ROWS(<font color="Green">C$1:C1</font>)-1,ROWS(<font color="Green">A$1:A$3</font>)</font>),1+INT(<font color="Red">(<font color="Green">ROWS(<font color="Purple">C$1:C1</font>)-1</font>)/ROWS(<font color="Green">A$1:A$3</font>)</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
Markmzz
 
Upvote 0
Why use VBA when a spreadsheet formula exists?
Spreadsheet formulas are usualy faster and more reliable than VB.
 
Upvote 0
Why use VBA when a spreadsheet formula exists?
Spreadsheet formulas are usualy faster and more reliable than VB.

...because this is a task that needs to be repeated many times each day on different worksheets and so creating a macro will be a lot easier.
 
Upvote 0
Thanks. Is there a way of achieving this using VBA, macro?
Assuming your Column A and B data starts in Row 1, give this macro a try...

Code:
Sub Sub AandBcombos()
  Dim X As Long, Z As Long, LastRowA As Long, LastRowB As Long
  LastRowA = Cells(Rows.Count, "A").End(xlUp).Row
  LastRowB = Cells(Rows.Count, "B").End(xlUp).Row
  For X = 1 To LastRowA
    For Z = 1 To LastRowB
      Cells(LastRowB * (X - 1) + Z, "C").Value = Cells(X, "A").Value & " " & Cells(Z, "B").Value
    Next
  Next
End Sub
 
Upvote 0
Thanks. Is there a way of achieving this using VBA, macro?

Maybe this:

Code:
Sub myComb()
    Dim myFormula As String
    Dim LastRow As Long
    Worksheets("Sheet8").Select
    LastRow = Range("A" & Rows.Count).End(xlUp).Row
    myFormula = "=INDEX(TRANSPOSE(A$1:A$" & LastRow & ")&"" ""&B$1:B$" & _
        LastRow & ",1+MOD(ROWS(F$1:F1)-1,ROWS(A$1:A$" & _
        LastRow & ")),1+INT((ROWS(F$1:F1)-1)/ROWS(A$1:A$" & LastRow & ")))"
    Range("C1").FormulaArray = myFormula
    If LastRow > 1 Then
        Range("C1").Copy Destination:=Range("C2:C" & LastRow * LastRow)
    End If
End Sub

Markmzz
 
Upvote 0

Forum statistics

Threads
1,224,505
Messages
6,179,152
Members
452,891
Latest member
JUSTOUTOFMYREACH

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