Skip to main content

Remove text after or before the second or nth space from text strings

Author: Xiaoyang Last Modified: 2021-12-03

Sometimes, you may need to remove all texts after or before the second or nth specific delimiter (such as space, comma, etc.) as following screenshot shown, this article, I will talk about some simple formulas for dealing with this task in Excel.


Remove text after the second or nth specific delimiter (space, comma, etc.) from text strings

In Excel, to remove the text after the second or nth space or other separators, the LEFT, SUBSTITUTE and FIND function can do you a favor. The generic syntax is:

=LEFT(SUBSTITUTE(cell," ","#",N+1),FIND("#",SUBSTITUTE(cell," ","#",N),1)-1)
  • cell: The cell reference or text string that you want to remove text from.
  • N: Represents the nth delimiter that you want to remove text based on.

Please copy or type the below formula into a blank cell where you want to get the result:

=LEFT(SUBSTITUTE(A2," ","#",3),FIND("#",SUBSTITUTE(A2," ","#",2),1)-1)

And then, drag the fill handle down to the cells that you want to apply this formula, and all texts after the second space have been deleted at once, see screenshot:

Explanation of the formula:

1. SUBSTITUTE(A2," ","#",3): This SUBSTITUTE function is used to replace the third space with a specific character # in cell A2. It will get this: “Tom Hill Houston#Texas US”. This part of formula is recognized as the text argument of the LEFT function.

2. FIND("#",SUBSTITUTE(A2," ","#",2),1)-1: This part of the formula is recgonized as the num_chars argument of the LEFT function.

  • SUBSTITUTE(A2," ","#",2): The SUBSTITUTE function will replace the second space with a specific # character in cell A2. And you will get the result as this: “Tom Hill#Houston Texas US”.
  • FIND("#",SUBSTITUTE(A2," ","#",2),1)-1=FIND("#", "Tom Hill#Houston Texas US", 1)-1: This FIND function is used to find the position of the # character from the text string returned by the SUBSTITUTE function start at the first character. Subtracting 1 means to exclude the space. And this will get the number 8.

3. LEFT(SUBSTITUTE(A2," ","#",3),FIND("#",SUBSTITUTE(A2," ","#",2),1)-1)=LEFT("Tom Hill Houston#Texas US", 8): Finally, this LEFT function will extract 8 characters from the left side of the text string in cell A2.

Notes:

1. If there are any other delimiters to separate your text string, you just need to replace the space character with other ones you need.

2. To remove the text after the nth specific delimiter, please change the nth number to your need, for example, to remove text after the third space, please apply the below formula:

=LEFT(SUBSTITUTE(A2," ","#",4),FIND("#",SUBSTITUTE(A2," ","#",3),1)-1)


Remove text before the second or nth specific delimiter (space, comma, etc.) from text strings

To remove the text before the second or nth specific delimiter, the RIGHT, LEN, FIND and SUBSTITUTE function can help you. The generic syntax is:

=RIGHT(cell,LEN(cell)-FIND("#",SUBSTITUTE(cell," ","#",N)))
  • cell: The cell reference or text string that you want to remove text from.
  • N: Represents the nth delimiter that you want to remove text based on.

Please copy or enter the below formula into a blank cell:

=RIGHT(A2,LEN(A2)-FIND("#",SUBSTITUTE(A2," ","#",2)))

Then, drag the fill handle down to the cells to apply this formula, and you will get the result as you need:

Explanation of the formula:

1. LEN(A2)-FIND("#",SUBSTITUTE(A2," ","#",2)):This part of formula is recognized as the num_chars argument of the RIGHT function.

  • SUBSTITUTE(A2," ","#",2): The SUBSTITUTE function will replace the second space with a specific # character in cell A2. And you will get the result as this: “Tom Hill#Houston Texas US”.
  • FIND("#",SUBSTITUTE(A2," ","#",2))=FIND("#", "Tom Hill#Houston Texas US" ): This FIND function will get the position of the # character of the text string which returned by the SUBSTITUTE function. And it will get the number 9.
  • LEN(A2)-FIND("#",SUBSTITUTE(A2," ","#",2))=25-9: The total length of cell A2 subtracts the position of the second space to get the number of the remaining character. This will get the number 16.

2. RIGHT(A2,LEN(A2)-FIND("#",SUBSTITUTE(A2," ","#",2)))=RIGHT(A2, 16): This RIGHT function is used to extract the characters from right side of the text in cell A2.

Notes:

1.If there are any other delimiters to separate your text string, you just need to replace the space character with other ones you need.

2. To remove the text before the nth specific delimiter, please change the nth number to your need, for example, to remove text after the third space, please apply the below formula:

=RIGHT(A2,LEN(A2)-FIND("#",SUBSTITUTE(A2," ","#",3)))


Relative functions used:

  • LEN:
  • The LEN function returns the number of characters in a text string.
  • LEFT:
  • The LEFT function extracts the given number of characters from the left side of a supplied string.
  • RIGHT:
  • The RIGHT function is used to extract a specific number of characters from the right side of the text string.
  • FIND:
  • The FIND function is used to find a string within another string, and returns the starting position of the string inside another one.
  • SUBSTITUTE:
  • The Excel SUBSTITUTE function replaces text or characters within a text string with another text or characters.

More articles:

  • Remove Text Within Parentheses Or Brackets From Text Strings
  • Supposing, you have a list of text strings, and part of the texts are enclosed in the parentheses, now, you want to remove all texts within the parentheses and including the parentheses themselves as below screenshot shown. This article, I will introduce some methods for solving this task in Excel.

The Best Office Productivity Tools

Kutools for Excel - Helps You To Stand Out From Crowd

🤖 Kutools AI Aide: Revolutionize data analysis based on: Intelligent Execution   |  Generate Code  |  Create Custom Formulas  |  Analyze Data and Generate Charts  |  Invoke Kutools Functions
Popular Features: Find, Highlight or Identify Duplicates  |  Delete Blank Rows  |  Combine Columns or Cells without Losing Data  |  Round without Formula ...
Super VLookup: Multiple Criteria  |  Multiple Value  |  Across Multi-Sheets  |  Fuzzy Lookup...
Adv. Drop-down List: Easy Drop Down List  |  Dependent Drop Down List  |  Multi-select Drop Down List...
Column Manager: Add a Specific Number of Columns  |  Move Columns  |  Toggle Visibility Status of Hidden Columns  Compare Columns to Select Same & Different Cells ...
Featured Features: Grid Focus  |  Design View  |  Big Formula Bar  |  Workbook & Sheet Manager | Resource Library (Auto Text)  |  Date Picker  |  Combine Worksheets  |  Encrypt/Decrypt Cells  |  Send Emails by List  |  Super Filter  |  Special Filter (filter bold/italic/strikethrough...) ...
Top 15 Toolsets12 Text Tools (Add Text, Remove Characters ...)  |  50+ Chart Types (Gantt Chart ...)  |  40+ Practical Formulas (Calculate age based on birthday ...)  |  19 Insertion Tools (Insert QR Code, Insert Picture from Path ...)  |  12 Conversion Tools (Numbers to Words, Currency Conversion ...)  |  7 Merge & Split Tools (Advanced Combine Rows, Split Excel Cells ...)  |  ... and more

Kutools for Excel Boasts Over 300 Features, Ensuring That What You Need is Just A Click Away...

Description


Office Tab - Enable Tabbed Reading and Editing in Microsoft Office (include Excel)

  • One second to switch between dozens of open documents!
  • Reduce hundreds of mouse clicks for you every day, say goodbye to mouse hand.
  • Increases your productivity by 50% when viewing and editing multiple documents.
  • Brings Efficient Tabs to Office (include Excel), Just Like Chrome, Edge and Firefox.
Comments (0)
No ratings yet. Be the first to rate!
There are no comments posted here yet
Please leave your comments in English
Posting as Guest
×
Rate this post:
0   Characters
Suggested Locations