Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 8 of 8

Thread: Removing "space" after imported numbers

  1. #1
    New Member
    Join Date
    Apr 2002
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    I import lists into Excel. Before formatting phone or fax numbers, I remove these characters ()- and "spaces" in the numbers. However, I sometimes find a "space" after the number. When I run a Find/Replace, where I find the "space" and then replace it with nothing, the "space" still remains and I cannot format it. Are you aware of this situation and what can I do to remove the "space" AFTER the numbers? BTW, this also occurs with Zip Codes as well.

  2. #2
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    83,647
    Post Thanks / Like
    Mentioned
    33 Post(s)
    Tagged
    6 Thread(s)

    Default

    On 2002-04-22 08:18, barrett@thebrooksgroup.com wrote:
    I import lists into Excel. Before formatting phone or fax numbers, I remove these characters ()- and "spaces" in the numbers. However, I sometimes find a "space" after the number. When I run a Find/Replace, where I find the "space" and then replace it with nothing, the "space" still remains and I cannot format it. Are you aware of this situation and what can I do to remove the "space" AFTER the numbers? BTW, this also occurs with Zip Codes as well.
    Try:

    =CODE(RIGHT(A1))

    where A1 houses a suspect entry.

    This will give you a number n, probably, 160.

    Use

    =SUBSTITUTE(A1,CHAR(n),"")+0

    +0 converts the entry to number after the cleaning.


    [ This Message was edited by: Aladin Akyurek on 2002-04-22 08:26 ]

  3. #3
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Are you sure that it's a space? What does =CODE(RIGHT(A1)) return where A1 is a cell containing one of your values?

  4. #4
    Board Regular
    Join Date
    Mar 2002
    Location
    =ActiveCell.Address
    Posts
    478
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    One solution would be to download the excellent asap-utilities from http://asap-utilities.com
    This has many handy formatting features, one of which is to "Delete leading trailing and excessive spaces"

  5. #5
    New Member
    Join Date
    Apr 2002
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    On 2002-04-22 08:23, Mark W. wrote:
    Are you sure that it's a space? What does =CODE(RIGHT(A1)) return where A1 is a cell containing one of your values?
    The value is 160 - now what do I do?

  6. #6
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    83,647
    Post Thanks / Like
    Mentioned
    33 Post(s)
    Tagged
    6 Thread(s)

    Default

    On 2002-04-22 08:39, barrett@thebrooksgroup.com wrote:
    On 2002-04-22 08:23, Mark W. wrote:
    Are you sure that it's a space? What does =CODE(RIGHT(A1)) return where A1 is a cell containing one of your values?
    I feel I'm repeating myself:

    =SUBSTITUTE(A1,CHAR(160),"")+0

    Copy down this as far as needed.

    The value is 160 - now what do I do?

  7. #7
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    On 2002-04-22 08:39, barrett@thebrooksgroup.com wrote:
    On 2002-04-22 08:23, Mark W. wrote:
    Are you sure that it's a space? What does =CODE(RIGHT(A1)) return where A1 is a cell containing one of your values?
    The value is 160 - now what do I do?

    In an unused or inserted column enter the formula, =LEFT(A1,LEN(A1)-1)+0. Copy down as far as needed. Copy/Paste Special... Values replaceing your original values with these new ones.

  8. #8
    New Member
    Join Date
    Apr 2002
    Posts
    3
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    On 2002-04-22 08:46, Aladin Akyurek wrote:
    On 2002-04-22 08:39, barrett@thebrooksgroup.com wrote:
    On 2002-04-22 08:23, Mark W. wrote:
    Are you sure that it's a space? What does =CODE(RIGHT(A1)) return where A1 is a cell containing one of your values?
    I feel I'm repeating myself:

    =SUBSTITUTE(A1,CHAR(160),"")+0

    Copy down this as far as needed.

    The value is 160 - now what do I do?
    Sorry about your repeating yourself. I got it to work. Thank you very much for your help.

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •