+ Reply to Thread
Results 1 to 5 of 5

Formula to trim text with spaces

  1. #1
    Registered User
    Join Date
    01-01-2010
    Location
    london, england
    MS-Off Ver
    Excel 2007
    Posts
    26

    Formula to trim text with spaces

    Hi,

    Hoping someone can help. I have an entry in Cell A1 that reads something like "FirstName SecondName Age Colour Sport Food Hobby". This is a feed from a third party software that changes periodically. In Cell B2 I would like to put a formula in so that I only get "Food" displayed. I guess this can be achieved using some form of trim and picking up the fact that spaces separate the data in the cell. However, the "Food" length varies in length and the only way of knowing the end of that field is when there is a space after it. Here are two possible examples that may be entered in cell A1:

    A1: "Brown Bobby 30 Green Rugby Pasta Fishing"

    A1: "Peters John 20 Blue Football Pizza Archery"

    In the first example, I would want cell B2 to return "Pasta" and in the second example, I would want cell B2 to return "Pizza"

    Is it possible to do this via a formula in B2? If so, grateful if someone could kindly post such an example. This is for a really good cause.

    Many thanks,

    Nick

  2. #2
    Forum Guru Andy Pope's Avatar
    Join Date
    05-10-2004
    Location
    Essex, UK
    MS-Off Ver
    O365
    Posts
    20,436

    Re: Formula to trim text with spaces

    to extract the sixith item delimitered by spaces try this.

    =LEFT(MID(SUBSTITUTE(TRIM(A1)," ","^",5),FIND("^",SUBSTITUTE(TRIM(A1)," ","^",5))+1,LEN(A1)),FIND(" ",MID(SUBSTITUTE(TRIM(A1)," ","^",5),FIND("^",SUBSTITUTE(TRIM(A1)," ","^",5))+1,LEN(A1)))-1)

    The SUBSITUTE formula places a known character at the space before the word. The uses the FIND to locate it. The LEFT of that substring is then extracted.
    Cheers
    Andy
    www.andypope.info

  3. #3
    Forum Expert
    Join Date
    05-30-2012
    Location
    The Netherlands
    MS-Off Ver
    Office 365
    Posts
    14,987

    Re: Formula to trim text with spaces

    Maybe you could use text to column.

    See the attached file.
    Attached Files Attached Files
    Notice my main language is not English.

    I appreciate it, if you reply on my solution.

    If you are satisfied with the solution, please mark the question solved.

    You can add reputation by clicking on the star * add reputation.

  4. #4
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Formula to trim text with spaces

    Hi,

    This - slightly shorter - formula will also extract the sixth item in a space-delimited string:

    =TRIM(MID(SUBSTITUTE(A1," ",REPT(" ",255)),5*255,255))

    Regards
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  5. #5
    Forum Guru (RIP) Marcol's Avatar
    Join Date
    12-23-2009
    Location
    Fife, Scotland
    MS-Off Ver
    Excel '97 & 2003/7
    Posts
    7,216

    Re: Formula to trim text with spaces

    Quote Originally Posted by XOR LX View Post
    Hi,

    This - slightly shorter - formula will also extract the sixth item in a space-delimited string:

    =TRIM(MID(SUBSTITUTE(A1," ",REPT(" ",255)),5*255,255))

    Regards
    I have no disagreement with this, however to allow for extra spaces in the data I would trim the source first then precede the string with a space to make the formula a litle more intuative.
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    See this workbook, select from the drop-down in B1
    Attached Files Attached Files
    If you need any more information, please feel free to ask.

    However,If this takes care of your needs, please select Thread Tools from menu above and set this topic to SOLVED. It helps everybody! ....

    Also
    اس کی مدد کرتا ہے اگر
    شکریہ کہنے کے لئے سٹار کلک کریں
    If you are satisfied by any members response to your problem please consider using the small Star icon bottom left of their post to show your appreciation.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. Trim Spaces(all)
    By JapanDave in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 02-09-2012, 10:05 PM
  2. Can't 'trim' or 'clean' spaces
    By [email protected] in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 02-05-2010, 07:06 PM
  3. trim leading spaces
    By captain bob in forum Excel General
    Replies: 2
    Last Post: 08-03-2006, 10:00 AM
  4. trim leading spaces
    By [email protected] in forum Excel General
    Replies: 10
    Last Post: 05-11-2006, 04:25 PM
  5. [SOLVED] How to trim spaces from entered text in cell using exisiting functions?
    By rj in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-19-2006, 03:45 PM

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