+ Reply to Thread
Results 1 to 5 of 5

Concatenate Possibly null cells & delimiting semicolon, and delete ending semicolon if any

  1. #1
    Registered User
    Join Date
    05-11-2013
    Location
    Chicago, IL
    MS-Off Ver
    Excel 2010
    Posts
    1

    Concatenate Possibly null cells & delimiting semicolon, and delete ending semicolon if any

    So I have six columns containing email addresses of different people connected to the respective rows. Many of the cells are empty. I need to combine them into a single cell for the user to copy-and-paste them all into the cc: list of an email message.

    So I drafted the following to concatenate them with a semi-colon & space between each. Then, if it ends in a semi-colon & space because of the final column being null, the semi-colon & space are trimmed off.

    It works, but is big and inelegant. Anyone have any better thoughts?

    =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,"")))</p>

    Thanks.

  2. #2
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    53,044

    Re: Concatenate Possibly null cells & delimiting semicolon, and delete ending semicolon if

    for a start, I prefer to use & instead of concatenate - it shortens the forumla and the & makes it easer to deterimine where 1 part ends and the next 1 starts (rather than ",")
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  3. #3
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    53,044

    Re: Concatenate Possibly null cells & delimiting semicolon, and delete ending semicolon if

    Try this instead?

    =if(a3="","",a3)&if(b3="","","; "&b3)&if(c3="","","; "&c3)&if(d3="","","; "&d3)&if(e3="","","; "&e3)&if(f3="","","; "&f3)
    Last edited by FDibbins; 05-11-2013 at 07:37 PM.

  4. #4
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Concatenate Possibly null cells & delimiting semicolon, and delete ending semicolon if

    since email address don't have spaces you can use
    =SUBSTITUTE(TRIM(A1&" "&B1&" "&C1&" "&D1&" "&E1&" "&F1)," ","; ")
    Last edited by martindwilson; 05-11-2013 at 07:40 PM.
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

  5. #5
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Concatenate Possibly null cells & delimiting semicolon, and delete ending semicolon if

    Are you open to using a VBA function for this?

    Copy the code below and paste it into a general module:

    Please Login or Register  to view this content.
    Then, you'd use it like this:

    =concatall(A3:F3,"; ")
    Biff
    Microsoft MVP Excel
    Keep It Simple Stupid

    Let's Go Pens. We Want The Cup.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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