concatenate a 100 cells

R

ROLG

concatenate maybe a hundred cells--A1&A2&A3&A4....A100--

WHAT FORMULA CAN I PLUG IN TO concatenate A1 THRU A100??

A1&:A100 THIS DOESN'T WOR
 
R

Ron Rosenfeld

concatenate maybe a hundred cells--A1&A2&A3&A4....A100--

WHAT FORMULA CAN I PLUG IN TO concatenate A1 THRU A100??

A1&:A100 THIS DOESN'T WORK

You could use this UDF and then enter the formula:

=SETSTRING(0,A1:A100)

To enter the UDF, <alt-F11> opens the VB Editor.
Ensure your project is highlighted in the Project Explorer window, then
Insert/Module and paste the code below into the window that opens:

-----------------------
Function SetString(SpacesBetween As Integer, _
ParamArray rg() As Variant) As String

'by Ron Rosenfeld

Dim c As Variant
Dim i As Long

For i = 0 To UBound(rg)
Select Case VarType(rg(i))
Case Is = vbArray + vbVariant
For Each c In rg(i)
SetString = SetString & Space(SpacesBetween) & c
Next
Case Is = vbString
SetString = SetString & Space(SpacesBetween) & rg(i)
End Select
Next i

SetString = Trim(SetString)

End Function
 
G

Gord Dibben

I believe you must use a User Defined Function or a macro.

=CONCATENATE(A1:A100) doesn't work.

A UDF........

Function ConCatRange(CellBlock As Range) As String
Dim Cell As Range
Dim sbuf As String
For Each Cell In CellBlock
If Len(Cell.text) > 0 Then sbuf = sbuf & Cell.text ' & ","
'if comma wanted, delete the ' in above line
Next
ConCatRange = Left(sbuf, Len(sbuf) - 1)
End Function

Usage is =ConCatRange(A1:A100)

Macro.............

Sub ConCat_Cells()
Dim x As Range
Dim y As Range
Dim z As Range
Dim w As String
Dim sbuf As String
On Error GoTo endit
w = InputBox("Enter the Type of De-limiter Desired")
Set z = Application.InputBox("Select Destination Cell", _
"Destination Cell", , , , , , 8)
Application.SendKeys "+{F8}"
Set x = Application.InputBox _
("Select Cells...Contiguous or Non-Contiguous", _
"Cells Selection", , , , , , 8)
For Each y In x
If Len(y.text) > 0 Then sbuf = sbuf & y.text & w
Next
z = Left(sbuf, Len(sbuf) - 1)
Exit Sub
endit:
MsgBox "Nothing Selected. Please try again."
End Sub

Copy/paste both or one of the above into a general module in your workbook.

ALT + F11 to get to Visual Basic Editor.

CRTL + r to open the Project Explorer.

Select your workbook/project and right-click>insert>module.

The UDF is used as a Function in a cell.

The macro can be run from Tools>Macro>Macros or a button.


Gord Dibben Excel MVP
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top