Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Concatenating Values from a Variable Number of Cells.

Concatenating Values from a Variable Number of Cells

Written by Allen Wyatt (last updated November 18, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003


Pam has two columns of data. In column A there are simple identifiers, such as A, B, C, etc. In column B there are a series of integer values. She can sort the data by the identifier and, secondarily, by the integer values. Now she wants, in column C, to have a formula that will concatenate all the integer values for a particular identifier. Thus, if A1:A4 all contain the identifier A, then in cell C1 she would like to have all the values in B1:B4 concatenated and divided by commas, such as "11, 17, 19, 25". Since the number of rows for each identifier can be different, Pam isn't sure how to go about the concatenation.

The easiest way to accomplish this is to use a macro, which can be created as a user-defined function. Here's an example:

Function CatSame(c As Range) As String
    Application.Volatile
    sTemp = ""
    iCurCol = c.Column
    If iCurCol = 3 Then
        If c.Row = 1 Then
            sLast = ""
        Else
            sLast = c.Offset(-1, -2)
        End If
        If c.Offset(0, -2) <> sLast Then
            J = 0
            Do
                sTemp = sTemp & ", " & c.Offset(J, -1)
                J = J + 1
            Loop While c.Offset(J, -2) = c.Offset(J - 1, -2)
            sTemp = Right(sTemp, Len(sTemp) - 2)
        End If
    End If
    CatSame = sTemp
End Function

This function basically takes a value that is passed to it (a cell reference) and verifies that the cell reference is for column C. If it is, then it starts to concatenate values from column B based on the values in column A. It only returns the string of concatenated values if the value is column A is different than the value in the row above it. Assuming your identifiers are in column A and your values to be concatenated are in column B, you could place the following in column C:

=CatSame(C1)

Copy this down as far as necessary in column C and you end up with exactly what Pam wanted.

A more versatile function would be one that would function somewhat like VLOOKUP, but bring back a concatenated list of values that match whatever you are looking up. Consider the following function:

Function VLookupAll(vValue, rngAll As Range, _
  iCol As Integer, Optional sSep As String = ", ")
    Dim rCell As Range
    Dim rng As Range
    On Error GoTo ErrHandler

    Application.Volatile
    Set rng = Intersect(rngAll, rngAll.Columns(1))
    For Each rCell In rng
        If rCell.Value = vValue Then _
          VLookupAll = VLookupAll & sSep & _
          rCell.Offset(0, iCol).Value
    Next rCell

    If VLookupAll = "" Then
        VLookupAll = CVErr(xlErrNA)
    Else
        VLookupAll = Right(VLookupAll, Len(VLookupAll) - Len(sSep))
    End If
ErrHandler:
    If Err.Number <> 0 Then VLookupAll = CVErr(xlErrValue)
End Function

This function takes up to four arguments. The first is the value you want to match in your lookup. In Pam's instance, this would be the identifier you want, such as A, B, or C. The second argument is the range of cells in which to look for the matches (column A in this case). The third argument is an offset (from the range in the second argument) that represents the values you want concatenated. You can use the function in this manner:

=VLookupAll("B",A1:A99,1)

If you want to specify a different delimiter between values, you can do it using the optional fourth argument. For instance, the following returns a string where a dash separates each value:

=VLookupAll("B",A1:A99,1,"-")

The solutions so far have focused on using macros. The reason for this is relatively simple: There isn't a formula-based solution that can do what Pam needs. Using nested IF statements to evaluate what is in column A won't work well because you are limited in how deeply IF statements can be nested.

You could use a formula and an intermediate result if you don't mind having the concatenated values be at the last instance of an identifier in column A. Start by putting this formula in cell C1:

=B1

This formula should go into cell C2:

=IF(A2=A1,C1 & ", " & B2, B2)

Copy this formula down as many rows as necessary. What you end up with is an increasingly long series of concatenated values in column C, with the longest in each run being on the same row as the last sequential identifier in column A. You can then put the following in all the applicable cells of column D:

=IF(LEN(C2)>LEN(C1),"",C1)

This formula only displays the longest strings from column C, which is what Pam needed to begin with.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9197) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Concatenating Values from a Variable Number of Cells.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Special Differences when Searching

Word includes two different search engines. Which search engine you choose to use will dictate what Word shows as ...

Discover More

Copying Headers and Footers

Need to get headers and footers from one document to another? You can use the steps in this tip to help make quick work ...

Discover More

Importing AutoCorrect Entries

The AutoCorrect feature in Word can be very helpful not just for correcting misspellings, but also for expanding short ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (menu)

Segregating Numbers According to Their Sign

Remember your number line from your early years in school? Some numbers can be below zero (negative numbers) and others ...

Discover More

Averaging a Non-Contiguous Range

Figuring out how to average data that is in a contiguous range of cells is easy. When the data is spread over a group of ...

Discover More

Using a Formula to Replace Spaces with Dashes

If you need a formula to change spaces to some other character, the SUBSTITUTE function fits the bill. Here's how to use it.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two more than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.