Extract tect from cell

sharky12345

Well-known Member
Joined
Aug 5, 2010
Messages
3,404
Office Version
  1. 2016
Platform
  1. Windows
Is there a way I can extract the word(s) after a specific word from a cell?

The contents of the cell are on numerous lines, so I would need something that searched the cell, finds the phrase 'INDEX:' and then grabs the word(s) after that, but on the same line only, and puts it/them into cell G4.

Anyone?
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
Give this UDF (user defined function) a try...
Code:
Function IndexWords(S As String) As String
  Dim Words() As String
  Words = Split(S, "INDEX:", 2)
  If UBound(Words) = 1 Then IndexWords = Split(Words(1), vbLf)(0)
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 IndexWords just like it was a built-in Excel function. For example, assuming your text is in cell A4, put this formula in cell G4 (the cell you said you wanted the outputted text to go to)..

=IndexWords(A4)

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
Thank you for the nice comments guys! I posted that UDF solution just before going to bed (I think in VBA faster than I do in Excel formulas). Now that I have just gotten up, two things have occurred to me. First, I think the output from my UDF needs a minor tweak to handle extraneous spaces. Here is the modified code to do that...
Code:
Function IndexWords(S As String) As String
  Dim Words() As String
  Words = Split(S, "INDEX:", 2)
  If UBound(Words) = 1 Then IndexWords = Application.Trim(Split(Words(1), vbLf)(0))
End Function

Second, there is a formula solution available to do this as well...

=TRIM(IF(COUNTIF(A1,"*INDEX:*"),LEFT(MID(A1,SEARCH("INDEX:",A1)+6,999)&CHAR(10),FIND(CHAR(10),MID(A1,SEARCH("INDEX:",A1)+6,999)&CHAR(10))-1),""))
 
Upvote 0
Rick, thank you - I had encountered the spaces problem but just used a separate routine to remove those, so although it works, yours is neater and I will change what I have. Thanks again!
 
Upvote 0
Give this formula a try too:

=MID(A1,FIND("INDEX:",A1&"INDEX:")+7,FIND(CHAR(10),A1&"INDEX:"&CHAR(10),FIND("INDEX:",A1&"INDEX:"&CHAR(10))+6)-FIND("INDEX:",A1&"INDEX:")-6)
 
Upvote 0
Rick,

Can you assist please?

I need to extract the date only from this field within the email and although the extraction works, it keeps giving me the date as '00/01/1900'.

Any ideas?

Claim created on: 02/09/2014 16:14
 
Upvote 0
Rick,

Can you assist please?

I need to extract the date only from this field within the email and although the extraction works, it keeps giving me the date as '00/01/1900'.

Any ideas?

Claim created on: 02/09/2014 16:14

That text does not have the word "INDEX:" in it, so my code, as written, will return nothing... change "INDEX:" to "on:" in the code and it should work.
 
Upvote 0
Thanks Rick,

I'd adjusted your code like this;

Code:
Function ExtractDATE(S As String) As String
Dim Words() As String
Words = Split(S, "Claim created on: ", 2)
If UBound(Words) = 1 Then ExtractDATE = Split(Words(1), vbLf)(0)
End Function

but that doesn't work - can you see something obvious?
 
Upvote 0

Forum statistics

Threads
1,214,400
Messages
6,119,292
Members
448,885
Latest member
LokiSonic

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