Concatenate With Delimiter

golfnut324

Board Regular
Joined
Jul 12, 2006
Messages
93
Can someone help me to concatenate across columns, say J through Q, (some of which are blank) and have the results delimited by a comma without returning anything for columns that might be blank. So R660 would read "0263B001A,FX9,FX-9,FX10,FX-10" and R669 would read "08A0477,GPR18,GPR-18". I need to apply this to a about 14000 rows in a worksheet.

Please help me with the details of vba and storing in a personal workbook.

Many thanks to all of your help time and time again.

Craig
Toner Data Base Load 01312009 0623.xls
JKLMNOPQR
6590263B001AFX9FX-9FX10FX-10
6600263B001AFX9FX-9FX10FX-10
6610264B001A
6620264B001A
6630264B001A
6640264B001A
6650264B001A
6660264B001A
6670264B001A
6680264B001A
6690384B003AAGPR18GPR-18
6700384B003AAGPR18GPR-18
67108A0477
Sheet1
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Use this popular UDF, StringConcat function for this.
http://www.cpearson.com/excel/stringconcatenation.aspx
Code:
Function StringConcat(Sep As String, ParamArray Args()) As String
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
' StringConcat
' This function concatenates all the elements in the Args array,
' delimited by the Sep character, into a single string. This function
' can be used in an array formula.
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
Dim S As String
Dim N As Long
Dim M As Long
Dim R As Range
Dim NumDims As Long
Dim LB As Long
Dim IsArrayAlloc As Boolean

'''''''''''''''''''''''''''''''''''''''''''
' If no parameters were passed in, return
' vbNullString.
'''''''''''''''''''''''''''''''''''''''''''
If UBound(Args) - LBound(Args) + 1 = 0 Then
    StringConcat = vbNullString
    Exit Function
End If


For N = LBound(Args) To UBound(Args)
    ''''''''''''''''''''''''''''''''''''''''''''''''
    ' Loop through the Args
    ''''''''''''''''''''''''''''''''''''''''''''''''
    If IsObject(Args(N)) = True Then
        '''''''''''''''''''''''''''''''''''''
        ' OBJECT
        ' If we have an object, ensure it
        ' it a Range. The Range object
        ' is the only type of object we'll
        ' work with. Anything else causes
        ' a #VALUE error.
        ''''''''''''''''''''''''''''''''''''
        If TypeOf Args(N) Is Excel.Range Then
            '''''''''''''''''''''''''''''''''''''''''
            ' If it is a Range, loop through the
            ' cells and create append the elements
            ' to the string S.
            '''''''''''''''''''''''''''''''''''''''''
            For Each R In Args(N).Cells
                S = S & R.Text & Sep
            Next R
        Else
            '''''''''''''''''''''''''''''''''
            ' Unsupported object type. Return
            ' a #VALUE error.
            '''''''''''''''''''''''''''''''''
            StringConcat = CVErr(xlErrValue)
            Exit Function
        End If
    
    ElseIf IsArray(Args(N)) = True Then
        
        On Error Resume Next
        '''''''''''''''''''''''''''''''''''''
        ' ARRAY
        ' If Args(N) is an array, ensure it
        ' is an allocated array.
        '''''''''''''''''''''''''''''''''''''
        IsArrayAlloc = (Not IsError(LBound(Args(N))) And _
            (LBound(Args(N)) <= UBound(Args(N))))
        On Error GoTo 0
        If IsArrayAlloc = True Then
            ''''''''''''''''''''''''''''''''''''
            ' The array is allocated. Determine
            ' the number of dimensions of the
            ' array.
            '''''''''''''''''''''''''''''''''''''
            NumDims = 1
            On Error Resume Next
            Err.Clear
            NumDims = 1
            Do Until Err.Number <> 0
                LB = LBound(Args(N), NumDims)
                If Err.Number = 0 Then
                    NumDims = NumDims + 1
                Else
                    NumDims = NumDims - 1
                End If
            Loop
            ''''''''''''''''''''''''''''''''''
            ' The array must have either
            ' one or two dimensions. Greater
            ' that two caues a #VALUE error.
            ''''''''''''''''''''''''''''''''''
            If NumDims > 2 Then
                StringConcat = CVErr(xlErrValue)
                Exit Function
            End If
            If NumDims = 1 Then
                For M = LBound(Args(N)) To UBound(Args(N))
                    If Args(N)(M) <> vbNullString Then
                        S = S & Args(N)(M) & Sep
                    End If
                Next M
                
            Else
                For M = LBound(Args(N), 1) To UBound(Args(N), 1)
                    If Args(N)(M, 1) <> vbNullString Then
                        S = S & Args(N)(M, 1) & Sep
                    End If
                Next M
                For M = LBound(Args(N), 2) To UBound(Args(N), 2)
                    If Args(N)(M, 2) <> vbNullString Then
                        S = S & Args(N)(M, 2) & Sep
                    End If
                Next M

            End If
        Else
            S = S & Args(N) & Sep
        End If
    Else
        S = S & Args(N) & Sep
    End If
Next N

'''''''''''''''''''''''''''''''''''
' Remove the trailing Sep character
'''''''''''''''''''''''''''''''''''
If Len(Sep) > 0 Then
    S = Left(S, Len(S) - Len(Sep))
End If

StringConcat = S

End Function
Then the array formula in R660 would be:

=StringConcat(",",IF($J660:$Q660<>"",$J660:$Q660,""))
..confirmed with CTRL-SHIFT-ENTER, not just ENTER or it won't work.

To add the code above to your sheet, press Alt-F11 to open the VBEditor.
Click Insert>Module
Paste in all the code above
Alt-F11 to close the editor
Save your sheet.

Now your StringConcat function is usable.
 
Last edited:
Upvote 0
If you wanted to, you could dispense with the VBA by using a lot of IF statements, like:

=IF(J1<>"",J1&",","")&IF(K1<>"",K1&",","")&IF(L1<>"",L1&",","")&IF(M1<>"",M1&",","")&IF(N1<>"",N1&",","")&IF(O1<>"",O1&",","")&IF(P1<>"",P1&",","")&IF(Q1<>"",Q1&",","")

but that will put a comma at the end of the string. If I were to do it that way, I'd use a hidden column for that result and create another formula like this, assuming the result is in (hidden column) "S":

=MID(S1,1,LEN(S1)-1)

which will eliminate the trailing comma. Just a thought..
 
Upvote 0
Thank you both for the quick response. I will try it both ways and post results. Both options are great to help me learn more about the functions.

Thanks,

Craig
 
Upvote 0
I'm a dummy with vba, please help once more! I followd the steps and when I enter the StringConcat function I get a Compile Error: Syntax Error and the first line of the code in vba editor is highlighted. Dumb question: Am I suppose to enter any parameter into the code to run on my sheet? And could you walk me through saving this to a personal.xls workbook so the code is there anytime I'm in Excel?

Much Thanks
 
Upvote 0
I can't get the VBA to work right either, even though I can see what it's supposed to do and all. The only thing that makes sense in your situation is that you may have put the code in a sheet/workbook/class module instead of a standard module, which will cause it to crash. The problem I'm having is with the array formula, the code runs OK, but I get like EVERY piece of data rather than the string you are after. At this point, I'd have to do some really close examination to determine what I'm doing wrong (or even IF I'm doing anything wrong)!
 
Upvote 0
The code comes right off the page referenced, I've used it many times, so it's good. Cut'n'paste...into a standard module.

Try a simple stringconcat first before the fancy one:

=Stringconcat(",",J660:R660)


Just press ENTER for the simple formula, you should get SOME response. Once that works, you can try the array:

=StringConcat(",",IF($J660:$Q660<>"",$J660:$Q660,""))

...confirmed with CTRL-SHIFT-ENTER to activate the array, not just ENTER or it won't work. The point of the array version is to have the blank cells not strew extra commas all through the results.
 
Last edited:
Upvote 0
I'm a dummy with vba, please help once more! I followd the steps and when I enter the StringConcat function I get a Compile Error: Syntax Error and the first line of the code in vba editor is highlighted. Dumb question: Am I suppose to enter any parameter into the code to run on my sheet? And could you walk me through saving this to a personal.xls workbook so the code is there anytime I'm in Excel?

Much Thanks

You can add stuff to your personal.xls, but the problem there is the addins aren't there when you give the book to someone else. By inserting the codes into your sheet when needed, it is always there for WHOEVER is using it, on any machine.

Once you have the code in your sheet, you can save the code "snippet" to make it easy to reimport anytime you need it. Just use FILE > EXPORT from inside the VBEditor. Next time it's needed, open the editor, FILE > Import.
 
Upvote 0
here's another custom vba function that might suit your needs. hold alt+f11 and paste the below code into a new vba module (Insert\Module). use like a regular excel function eg = myCate(J659:Q659):


Code:
Private Function myCate(Target As Range)
 
Dim c As Range
Dim Temp As String
 
For Each c In Target
 
If c = "" Then
     'do nothing
  Else
     Temp = Temp & c.Value & ","
End If
 
Next
 
myCate = Mid(Temp, 1, Len(Temp) - 1)
 
End Function
 
Upvote 0

Forum statistics

Threads
1,216,116
Messages
6,128,933
Members
449,480
Latest member
yesitisasport

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