Concatenating Names with Delimiters

Written by Allen Wyatt (last updated June 12, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003


Chris has a worksheet that has customer names in columns A through F. In column G he wants to include a formula that will take all the names from the six name columns and concatenate them into one long string, with the characters // between each name. It is possible that there won't be names in all six columns, and there should be no extraneous leading or trailing // delimiters.

Concatenating text in Excel is easy. For instance, if you have something in cell A2 and you want to concatenate it with what is in cell B2, you can do so with this formula:

=A2 & B2

You could include the // delimiters between the two values by simply adding them into the proper place:

=A2 & "//" & B2

This is pretty easy. Using this approach, you could concatenate all six names using the following formula:

=A2 & "//" & B2 & "//" & C2 & "//" & D2 & "//" & E2 & "//" & F2

Where things get tricky is when you recognize that some of those cells may have nothing in them. Thus, the formula would result in either trailing or ending // delimiters, or in double delimiters (////) somewhere in the middle of the result.

The obvious solution is to use IF statements to check the contents of the name cells before concatenating them. This, however, can result in some amazingly long formulas. For instance, the following formula will correctly do the checking and concatenation:

=IF(RIGHT(CONCATENATE(IF(A3="","",CONCATENATE(A3,"//")),
IF(B3="","",CONCATENATE(B3,"//")),IF(C3="","",CONCATENATE(C3,"//")),
IF(D3="","",CONCATENATE(D3,"//")),IF(E3="","",CONCATENATE(E3,"//")),
IF(F3="","",F3)),2)="//",LEFT(CONCATENATE(IF(A3="","",
CONCATENATE(A3,"//")),IF(B3="","",CONCATENATE(B3,"//")),
IF(C3="","",CONCATENATE(C3,"//")),IF(D3="","",CONCATENATE(D3,"//")),
IF(E3="","",CONCATENATE(E3,"//")),IF(F3="","",F3)),
LEN(CONCATENATE(IF(A3="","",CONCATENATE(A3,"//")),
IF(B3="","",CONCATENATE(B3,"//")),IF(C3="","",CONCATENATE(C3,"//")),
IF(D3="","",CONCATENATE(D3,"//")),IF(E3="","",CONCATENATE(E3,"//")),
IF(F3="","",F3)))-2),CONCATENATE(IF(A3="","",CONCATENATE(A3,"//")),
IF(B3="","",CONCATENATE(B3,"//")),IF(C3="","",CONCATENATE(C3,"//")),
IF(D3="","",CONCATENATE(D3,"//")),IF(E3="","",CONCATENATE(E3,"//")),
IF(F3="","",F3)))

Yes, this is a single-line formula. (Whew!) This formula uses the approach of nesting IF statements to achieve the desired result. This may work in this particular instance, but the formula runs very close to Excel's limit of only allowing IF statements to be nested to seven levels deep.

The solution to the potential nested levels problem is to just not nest the IF statements. Instead, you can evaluate each cell individually and concatenate whatever is returned.

=MID(IF(ISTEXT(A3),"//"&A3,"") & IF(ISTEXT(B3),"//"&B3,"")
& IF(ISTEXT(C3),"//"&C3,"") & IF(ISTEXT(D3),"//"&D3,"") &
IF(ISTEXT(E3),"//"&E3,"") & IF(ISTEXT(F3),"//"&F3,""),3,2000)

Notice that this formula is much shorter. You can better see what it is doing if you look at the formula "broken out" onto multiple lines:

=MID(
IF(ISTEXT(A3),"//"&A3,"") &
IF(ISTEXT(B3),"//"&B3,"") &
IF(ISTEXT(C3),"//"&C3,"") &
IF(ISTEXT(D3),"//"&D3,"") &
IF(ISTEXT(E3),"//"&E3,"") &
IF(ISTEXT(F3),"//"&F3,""),3,2000)

Each individual IF statement in the formula evaluates a name cell and either returns nothing ("") if the cell contains no text, or it returns the delimiter (//) followed by the name. The entire formula is then enclosed within the MID statement which effectively cuts off the first // delimiter in the string.

This formula can be shortened even more if, instead of using the ISTEXT function to evaluate the cells, you simply do a Boolean comparison to find out if any text is in the cell, as follows:

=MID(IF(A3>"","//"&A3,"") & IF(B3>"","//"&B3,"") &
IF(C3>"","//"& C3,"") & IF(D3>"","//"&D3,"") &
IF(E3>"","//"&E3,"") & IF(F3>"","//"&F3,""),3,2000)

This is the exact same technique, just a bit shorter. (And quite a bit shorter from the original formula.)

This formula will work great, provided that the values in the name cells are text. If your name columns have numeric values in them for some reason, you can easily modify the formula to use ISBLANK instead of ISTEXT, as shown here:

=MID(IF(ISBLANK(A3),"","//"&A3) & IF(ISBLANK(B3),"","//"&B3)
& IF(ISBLANK(C3),"","//"& C3) & IF(ISBLANK(D3),"","//"&D3)
& IF(ISBLANK(E3),"","//"&E3) & IF(ISBLANK(F3),"","//"&F3),3,2000)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2173) applies to Microsoft Excel 97, 2000, 2002, and 2003.

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

Increasing Row Height for Printing

You may have a need to increase the height of the rows in your worksheet to "spread out" the data when it is printed. ...

Discover More

Changing Months in a Workbook

When you copy a worksheet and then need to make changes to information in that worksheet (such as changing month names), ...

Discover More

Converting Text to Numbers

Import information from a program external to Excel, and your numbers may be treated as text because of the way that the ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (menu)

Returning the Left-most Characters

When working with text in a formula, you may need to extract the left-most characters from a string of text or from a ...

Discover More

Checking for Text

Need to figure out if a particular cell contains text? You can use the ISTEXT function to easily return this bit of trivia.

Discover More

Repeating Cell Contents

Want to repeat cell contents over and over again within a single cell? Excel provides two ways you can duplicate the content.

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 2 + 8?

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.