+ Reply to Thread
Results 1 to 4 of 4

Inserting Characters

  1. #1
    Registered User
    Join Date
    06-08-2005
    Posts
    9

    Question Inserting Characters

    So I have a column of zip codes - some with 5 numbers and some with 9. What I am trying to do is create a formula where if there are more than 5 characters in that cell, insert a "-" after the 5th character from the left...does anyone know how to do that?

    what I am trying to do...
    before:
    503122540

    after:
    50312-2540

    without going through each cell manually!

    Thanks

  2. #2
    Valued Forum Contributor Excelenator's Avatar
    Join Date
    07-25-2006
    Location
    Wantagh, NY
    Posts
    333
    You could use this formula in an adjacent cell and copy it down the column, then copy the results and paste special values over the original data (if you want to replace the data ONLY) then remove the calculated column.

    =IF(LEN(A1)>5,MID(A1,1,5) & "-" & MID(A1,6,50),A1)
    ---------------------------------------------------
    ONLY APPLIES TO VBA RESPONSES WHERE APPROPRIATE
    To insert code into the VBE (Visual Basic Editor)
    1. Copy the code.
    2. Open workbook to paste code into.
    3. Right click any worksheet tab, select View Code
    4. VBE (Visual Basic Editor) opens to that sheets object
    5. You may change to another sheets object or the This Workbook object by double clicking it in the Project window
    6. In the blank space below the word "General" paste the copied code.

  3. #3
    Ron Rosenfeld
    Guest

    Re: Inserting Characters

    On Fri, 18 Aug 2006 11:16:29 -0400, rae820
    <[email protected]> wrote:

    >
    >So I have a column of zip codes - some with 5 numbers and some with 9.
    >What I am trying to do is create a formula where if there are more than
    >5 characters in that cell, insert a "-" after the 5th character from the
    >left...does anyone know how to do that?
    >
    >what I am trying to do...
    >before:
    >503122540
    >
    >after:
    >50312-2540
    >
    >without going through each cell manually!
    >
    >Thanks


    =TEXT(A1,"[>99999]00000-0000;00000")

    will do what you describe and also retain any leading zeros.
    --ron

  4. #4
    Ron Rosenfeld
    Guest

    Re: Inserting Characters

    On Fri, 18 Aug 2006 11:56:49 -0400, Excelenator
    <[email protected]> wrote:

    >
    >You could use this formula in an adjacent cell and copy it down the
    >column, then copy the results and paste special values over the
    >original data (if you want to replace the data ONLY) then remove the
    >calculated column.
    >
    >=IF(LEN(A1)>5,MID(A1,1,5) & "-" & MID(A1,6,50),A1)



    Of course, if the zip code has a leading zero, as mine does, your formula does
    not give useful results:

    046670208

    Your formula gives: 46670-208 when a more useful result would be 04667-0208

    See my response for a different solution.
    --ron

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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