extracting words from the word string

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
lukasz_rz,

Welcome to the MrExcel forum.

You are posting a picture. This means that if this was a problem where one needed to use your data, anyone trying to help you would have to enter the data manually. That makes no sense.

What version of Excel are you using?

Can you post a screenshot of the raw data worksheet, and, post a screenshot of the worksheet results (manually formatted by you) that you are looking for?

To post your data, you can download and install one of the following two programs:
Excel Jeanie
MrExcel HTML Maker


If you are not able to give us screenshots:
You can upload your workbook to Box Net,
sensitive data changed
mark the workbook for sharing
and provide us with a link to your workbook.
 
Upvote 0
lukasz_rz,

Your link is asking for an ID and Password?

You should try to mark the workbook for sharing, and, provide us with a link to your workbook.
 
Upvote 0
Maybe this:

Layout

cowdoggiraffeelephantparrot
*
*
Result1Result2Result3Result4Result5Data
cow cow makes muu
giraffe giraffe is tall
elephant elephant is big
parrot parrot is a colorful bird
dog each little dog is cute
dog dog eats meat
giraffe giraffe eats leafes
elephant elephant has a huge trump
parrot parrot can make human's voices
giraffe giraffe can be met in Africa
dog Once I had a dog but it ran away.
cow some cows give a lot of milk
elephant elephant is the biggest animal on the planet
elephantparrot elephant is bigget than a parrot
**********************************************************************************

<colgroup><col width="50" style="width: 38pt; mso-width-source: userset; mso-width-alt: 1828;"> <col width="47" style="width: 35pt; mso-width-source: userset; mso-width-alt: 1718;" span="2"> <col width="50" style="width: 38pt; mso-width-source: userset; mso-width-alt: 1828;"> <col width="47" style="width: 35pt; mso-width-source: userset; mso-width-alt: 1718;"> <col width="219" style="width: 164pt; mso-width-source: userset; mso-width-alt: 8009;"> <tbody>
</tbody>

Array formula in A5 - use Ctrl+Shift+Enter and not only Enter to enter the formula

Code:
=IFERROR(INDEX($A$1:$E$1,SMALL(IF(COUNTIF($F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),COLUMNS($A5:A5))),"")

And copy to the right until E5 and down.

Markmzz
 
Upvote 0
Maybe this:

Layout

cowdoggiraffeelephantparrot
*
*
Result1Result2Result3Result4Result5Data
cowcow makes muu
giraffegiraffe is tall
elephantelephant is big
parrotparrot is a colorful bird
dogeach little dog is cute
dogdog eats meat
giraffegiraffe eats leafes
elephantelephant has a huge trump
parrotparrot can make human's voices
giraffegiraffe can be met in Africa
dogOnce I had a dog but it ran away.
cowsome cows give a lot of milk
elephantelephant is the biggest animal on the planet
elephantparrotelephant is bigget than a parrot
**********************************************************************************

<tbody>
</tbody>

Array formula in A5 - use Ctrl+Shift+Enter and not only Enter to enter the formula

Code:
=IFERROR(INDEX($A$1:$E$1,SMALL(IF(COUNTIF($F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),COLUMNS($A5:A5))),"")

And copy to the right until E5 and down.

Markmzz

You are brillant, Markmzz.

One more small question. What to do with the last row, where I have two different animals. And the purpose is to have it all put in one column (first one) . Is it possible to put it together in one cell after "space" or "/",

or even better, prioritize one animal and ignore the another one?

I will really appreciate.
 
Upvote 0
lukasz_rz,

Thanks for the workbook.

The macro (using three arrays in memory) will adjust for a varying number of words in row 1, and, for a varying number of strings beginning in cell F5, down.

Sample raw data:


Excel 2007
ABCDEFG
1cowdoggiraffeelephantparrot
2
3
4
5cow makes muu
6giraffe is tall
7elephant is big
8parrot is a colorful bird
9each little dog is cute
10dog eats meat
11giraffe eats leafes
12elephant has a huge trump
13parrot can make human's voices
14giraffe can be met in Africa
15Once I had a dog but it ran away.
16some cows give a lot of milk
17elephant is the biggest animal on the planet
18elephant is bigget than a parrot
19
Sheet1


After the macro:


Excel 2007
ABCDEFG
1cowdoggiraffeelephantparrot
2
3
4
5cowcow makes muu
6giraffegiraffe is tall
7elephantelephant is big
8parrotparrot is a colorful bird
9dogeach little dog is cute
10dogdog eats meat
11giraffegiraffe eats leafes
12elephantelephant has a huge trump
13parrotparrot can make human's voices
14giraffegiraffe can be met in Africa
15dogOnce I had a dog but it ran away.
16cowsome cows give a lot of milk
17elephantelephant is the biggest animal on the planet
18elephant / parrotelephant is bigget than a parrot
19
Sheet1


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Option Explicit
Sub ExtractWords()
' hiker95, 10/13/2013
' http://www.mrexcel.com/forum/excel-questions/732529-extracting-words-word-string.html
Dim L, a As Variant, f As Variant
Dim i As Long, ii As Long, h As String, c As Long
L = Range(Cells(1, 1), Cells(1, Cells(1, Columns.Count).End(xlToLeft).Column))
f = Range("F5:F" & Range("F" & Rows.Count).End(xlUp).Row)
ReDim a(1 To UBound(f, 1), 1 To 1)
For i = LBound(f, 1) To UBound(f, 1)
  h = ""
  For c = LBound(L, 2) To UBound(L, 2)
    If InStr(f(i, 1), Trim(L(1, c))) > 0 Then
      h = h & Trim(L(1, c)) & " / "
    End If
  Next c
  If Right(h, 3) = " / " Then
    a(i, 1) = Left(h, Len(h) - 3)
  End If
Next i
With Range("A5").Resize(UBound(f, 1))
  .ClearContents
  .Value = a
  .Columns(1).AutoFit
End With
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm

Then run the ExtractWords macro.
 
Upvote 0
You are brillant, Markmzz.

One more small question. What to do with the last row, where I have two different animals. And the purpose is to have it all put in one column (first one) . Is it possible to put it together in one cell after "space" or "/",

or even better, prioritize one animal and ignore the another one?

I will really appreciate.

With formula, you can use this big array formula:

Array formula in A5 - use Ctrl+Shift+Enter and not only Enter to enter the formula

Code:
=IFERROR(INDEX($A$1:$E$1,SMALL(IF(COUNTIF(F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),1)),"")&
IFERROR(" / "&INDEX($A$1:$E$1,SMALL(IF(COUNTIF(F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),2)),"")&
IFERROR(" / "&INDEX($A$1:$E$1,SMALL(IF(COUNTIF(F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),3)),"")&
IFERROR(" / "&INDEX($A$1:$E$1,SMALL(IF(COUNTIF(F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),4)),"")&
IFERROR(" / "&INDEX($A$1:$E$1,SMALL(IF(COUNTIF(F5,"*"&$A$1:$E$1&"*"),COLUMN($A$1:$E$1)-COLUMN($A$1)+1),5)),"")

And copy down.

Or you can use Hiker95's code.

Markmzz
 
Upvote 0

Forum statistics

Threads
1,214,988
Messages
6,122,620
Members
449,092
Latest member
amyap

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