Search Text in string and return a value from table

krishnanshu

New Member
Joined
Aug 29, 2014
Messages
8
Here is the table of raw data

Hi, I will call Sonia to come and get Nidhi from US for the party
R u going to teach in the school, where Rashi is teaching
Hi, I went to california and I saw Nidhi over there. I think she has shifted
I would like to me Karl in office today

<tbody>
</tbody>

<colgroup><col></colgroup><tbody>
</tbody>

I would like These words to be searched in sequential order from L1 to L4 column. If any found, return with value of L5 in new column

L1L2L3L4L5
GopalBabuVenkatNidhiSunnyvale
SudeepSameerRashiBalaLos angeles
SoniaArunSatishJeedaNew York
ABCMonikaKarlMNOSan Jose

<colgroup><col><col><col><col><col></colgroup><tbody>
</tbody>

<tbody>
</tbody>
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Hi,

Did part of your tables get somehow cut off by the editor? Can you re-check? Appears to be data missing.

Regards
 
Upvote 0
I would like These words to be searched in sequential order from L1 to L4 column.

Ok, thanks. I think I understand.

But can you confirm what your interpretation is of "in sequential order"? So in cases where more than one of those strings is present, what determines which one takes precedence?

For example, if both Sudeep and Babu were present in a given string, should Sunnyvale or Los Angeles be retuned?

In short, does "sequential order" mean "rows-first" or "columns-first"?

Regards
 
Upvote 0
I still can't work out from your descriptions in which cells your tables are (I don't understand the L1-L5 references?), but assuming the second table is in A1:E5, such that Gopal is in A1 and San Jose in E5, and that your results table is in G1:G4, then, in H1:

If you're using Excel 2010 or later:

=INDEX($E$1:$E$4,AGGREGATE(15,6,ROW($A$1:$D$4)/ISNUMBER(SEARCH(" "&$A$1:$D$4&" "," "&G1&" ")),1))

Otherwise, array formula**:

=INDEX($E$1:$E$4,MIN(IF(ISNUMBER(SEARCH(" "&$A$1:$D$4&" "," "&G1&" ")),ROW($A$1:$D$4))))

Copy down to give similar results for the strings in G2, G3 and G4.

Regards


**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
 
Upvote 0
Actual dataexpected out put
Hi, I will call Sonia to come and get Nidhi from US for the partyNew york
R u going to teach in the school, where Rashi is teachingLos angeles
Hi, I went to california and I saw Nidhi over there. I think she has shiftedSunnyvale
I would like to me Karl in office todaysan Jose

<colgroup><col><col></colgroup><tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,213,526
Messages
6,114,122
Members
448,550
Latest member
CAT RG

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