+ Reply to Thread
Results 1 to 2 of 2

Concatenating Multiple Rows

Hybrid View

  1. #1
    Registered User
    Join Date
    07-24-2013
    Location
    Clovis
    MS-Off Ver
    Excel 2010
    Posts
    3

    Concatenating Multiple Rows

    So I am able to concatenate the same rows. I am trying to make a street index. Right now I have The same street name in multiple rows, but I would like One street name showing the Index with Commas. Example for right now: ROAD A: A1
    ROAD A: A2, ROAD A: A3. So those three entries are each a row, and I would like it to read ROAD A: A1, A2, A3.
    Thank you.

  2. #2
    Forum Expert tigeravatar's Avatar
    Join Date
    03-25-2011
    Location
    Colorado, USA
    MS-Off Ver
    Excel 2003 - 2013
    Posts
    5,361

    Re: Concatenating Multiple Rows

    bmcleer,

    Unfortunately, Excel's native CONCATENATE() function doesn't work with arrays. This means that there is no way Excel can perform what you're asking for without the use of VBA or an add-in.
    It is for this reason that I recommend the ConcatAll UDF I created:
    Public Function ConcatAll(ByVal varData As Variant, Optional ByVal sDelimiter As String = vbNullString, Optional ByVal bUnique As Boolean = False) As String
    'Created by TigerAvatar at www.excelforum.com, September 2012
    'Purpose is to concatenate many strings into a single string
    'Can be used with arrays, range objects, and collections
        
        Dim DataIndex As Variant    'Used to loop through arrays, range objects, and collections
        Dim strResult As String     'Used to build the result string
        
        'Test if varData is an Array, Range, or Collection
        If IsArray(varData) _
        Or TypeOf varData Is Range _
        Or TypeOf varData Is Collection Then
            
            'Found to be an, array, range object, or collection
            'Loop through each item in varData
            For Each DataIndex In varData
                'Check if the item isn't empty
                If Len(DataIndex) > 0 Then
                    'Found the item isn't empty, check if user specified bUnique as True
                    If bUnique = True Then
                        'bUnique is true, check if the item has been included in the result yet
                        If InStr(1, "||" & strResult & "||", "||" & DataIndex & "||", vbTextCompare) = 0 Then
                            'Item has not been included in the result, add item to the result
                            strResult = strResult & "||" & DataIndex
                        End If
                    Else
                        'bUnique is not true, add item to the result
                        strResult = strResult & "||" & DataIndex
                    End If
                End If
            Next DataIndex
            
            'Correct strResult to remove beginning delimiter and convert "||" to the specified sDelimiter
            strResult = Replace(Mid(strResult, 3), "||", sDelimiter)
            
        Else
            'Found not to be an array, range object, or collection
            'Simply set the result = varData
            strResult = varData
        End If
        
        'Output result
        ConcatAll = strResult
        
    End Function


    How to use a User Defined Function (UDF):
    1. Make a copy of the workbook the macro will be run on
      • Always run new code on a workbook copy, just in case the code doesn't run smoothly
      • This is especially true of any code that deletes anything
    2. In the copied workbook, press ALT+F11 to open the Visual Basic Editor
    3. Insert | Module
    4. Copy the provided code and paste into the module
    5. Close the Visual Basic Editor



    Then, you can use this formula to concatenate the items:
    =ConcatAll(INDEX(REPT(B1:B10,--(A1:A10="Road A")),),", ")
    Hope that helps,
    ~tigeravatar

    Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Concatenating multiple rows in Excel
    By Prexo in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 05-29-2013, 01:21 PM
  2. Concatenating Rows? Is this possible using IF?
    By beauxj26 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-15-2013, 05:07 PM
  3. Concatenating Several Rows
    By chome4 in forum Excel General
    Replies: 8
    Last Post: 07-13-2010, 05:13 AM
  4. Copying concatenating two rows in a macro
    By Seafury in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 04-22-2009, 06:05 PM
  5. concatenating rows from different sheets
    By ExcelWolfie in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-27-2006, 01:35 PM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1