Remove before and after space

Russk68

Well-known Member
Joined
May 1, 2006
Messages
589
Office Version
  1. 365
Platform
  1. MacOS
Hi
I need to remove the numbers on each side of the string. Remove before first space and after last space. I have formulas to do each one but not both.
Before and after, below.
TIA!
2 Mac Viper Profile 16 bit Extended (2)
Mac Viper Profile 16 bit Extended
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
If you wait a while, I am sure that others will come up with much better options but in the meantime this should work.
Wrap it in an IfError if your data is not consistent.

Book1
AB
1OriginalExtract
2123 test 456test
Sheet1
Cell Formulas
RangeFormula
B2B2=LEFT(RIGHT(A2,LEN(A2)-FIND(" ",A2)),FIND(" ",RIGHT(A2,LEN(A2)-FIND(" ",A2)))-1)
 
Upvote 0
If you wait a while, I am sure that others will come up with much better options but in the meantime this should work.
Wrap it in an IfError if your data is not consistent.

Book1
AB
1OriginalExtract
2123 test 456test
Sheet1
Cell Formulas
RangeFormula
B2B2=LEFT(RIGHT(A2,LEN(A2)-FIND(" ",A2)),FIND(" ",RIGHT(A2,LEN(A2)-FIND(" ",A2)))-1)
Hi Alex
The result that I got is "Mac"
Thee result I need is "Mac Viper Profile 16 bit Extended"
Thanks!
 
Upvote 0
Try this...but I think a UDF might be better
Excel Formula:
=MID(A1,SEARCH(" ",A1)+1,LOOKUP(2,1/(MID($A1,ROW(INDIRECT("1:"&LEN($A1))),1)=" "),ROW(INDIRECT("1:"&LEN($A1))))-(SEARCH(" ",A1)))
 
Upvote 0
Solution
Try this...but I think a UDF might be better
Excel Formula:
=MID(A1,SEARCH(" ",A1)+1,LOOKUP(2,1/(MID($A1,ROW(INDIRECT("1:"&LEN($A1))),1)=" "),ROW(INDIRECT("1:"&LEN($A1))))-(SEARCH(" ",A1)))
That works great!
Whats a UDF?
Thank you Mike
 
Upvote 0
The UDF for this is extremely simple...
VBA Code:
Function TrimIt(S As String) As String
  TrimIt = Trim(S)
End Function

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use TrimIt just like it was a built-in Excel function. For example,

=TrimIt(A1)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
@Rick Rothstein
I don't believe it is as simple as you have alluded, as the OP wants to find the text between 2 spaces ( 1st and last)
 
Upvote 0
@Rick Rothstein
I don't believe it is as simple as you have alluded, as the OP wants to find the text between 2 spaces ( 1st and last)
Whoops! You are right... I completely misread the question.:mad:

This UDF will do what the OP wanted (assuming I understand what that is now)...
VBA Code:
Function TrimIt(S As String) As String
  TrimIt = Split(Left(S, InStrRev(S, " ") - 1), " ", 2)(1)
End Function

And here is another way to write this same function (the OP can take his choice)...

VBA Code:
Function TrimIt(S As String) As String
  TrimIt = Mid(Left(S, InStrRev(S, " ") - 1), InStr(S, " ") + 1)
End Function
 
Upvote 0
another option

Excel Formula:
=MID(A2,(SEARCH(" ",A2)+1),FIND("*",SUBSTITUTE(A2," ","*",LEN(A2)-LEN(SUBSTITUTE(A2," ",""))))-(SEARCH(" ",A2)+1))
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,917
Members
452,366
Latest member
TePunaBloke

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top