Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Concatenating Names with Delimiters

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.

Related Tips:

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

awyatt    16 Sep 2014, 10:38
The 3 means "start with the third character" and the 2000 means "include the next 2000 characters." They are parameters for the MID function.

-Allen
Naomi Pierce    16 Sep 2014, 10:24
Could you tell us why you have the numbers 3,2000 at the end of the formula?
Michael (Micky) Avidan    15 Mar 2014, 15:25
The above tip demands a use of a User Defined Function [UDF] - especially if we need to concatenate a HUGE amount of cells - as shown in the picture:
http://srv2.jpg.co.il/2/5324a71ebd9b8.png
This sort of solution becomes even more essential when we handle more than 7 nested IFs (versions 97-2003).
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL




deepan    14 Mar 2014, 06:44
Dear Sir,

Please tell me any shortcut formulas for following examples formula.
=(A1*b1+c1*d1+e1*f1+g1*h1+i1*j1)
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.