efficient way to extract the nth word of a string

Heats

New Member
Joined
Jul 25, 2010
Messages
15
Is there an efficient way to extract the nth word of a string, for example if the string is;

"Create multistep table Playpen_Test.TablenameOne more SQL code etc"

I want to extract the following

Playpen_Test.TablenameOne

Baring in mind the name may change in length.

I have been trying to use the find function looking for the 3rd and 4th space and limiting the characters between them but not had much luck.

Many thanks if anyone can help
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
42,312
Office Version
365
Platform
Windows
Try this sort of idea:

=TRIM(MID(SUBSTITUTE(A1," ",REPT(" ",100)),300,100))

Depending on how far through the list of words you are looking and how long the 'words' are, you may need to tweak the multiples of 100.
 

Heats

New Member
Joined
Jul 25, 2010
Messages
15
It works, I will have a play around with it in the VB side now.

Many thanks Peter,
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
42,312
Office Version
365
Platform
Windows
It works, I will have a play around with it in the VB side now.

Many thanks Peter,
In that case, I suggest playing with something like this

<font face=Courier New><br><SPAN style="color:#00007F">Sub</SPAN> ExtractNthWord()<br>    <SPAN style="color:#00007F">Dim</SPAN> nWord <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">String</SPAN><br><br>    <SPAN style="color:#00007F">Const</SPAN> N <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN> = 4 <SPAN style="color:#007F00">'<-- 4th word</SPAN><br>    <br>    nWord = Split(Range("A1").Value, " ")(N - 1)<br>    MsgBox nWord<br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>
 

Forum statistics

Threads
1,082,558
Messages
5,366,309
Members
400,882
Latest member
zaldy_a

Some videos you may like

This Week's Hot Topics

Top