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
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
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.
 
Upvote 0
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>
 
Upvote 0

Forum statistics

Threads
1,223,681
Messages
6,173,812
Members
452,535
Latest member
berdex

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