Return valuse that contain a string or two strings

Damo71

Board Regular
Joined
Aug 17, 2010
Messages
88
Hi

I have a list of book titles in A1:100.

In cell C1 the user enters a string of one word (and, if possible, two words separated by a space*)

In cells D1 to D5 I need formulas to return the full book titles that contain the word or words the user has entered.

*e.g. if "Journey to the Center of the Earth" is in A1, and the user enters "Journey Earth" in C1, then D1 will return
"Journey to the Center of the Earth", the next matching entry will be in D2 and so on, up to 5 matches. If not possible with multiple words could you please help me with just a single string?

How can I do this please?

Many thanks
 
Last edited:
Try this small modification (Array Formula - use Ctrl+Shift+Enter to enter the formula):

=IFERROR(INDEX($A$1:$A$10,
SMALL(IF(MMULT(--ISNUMBER(SEARCH(" "&TRIM(MID(SUBSTITUTE($C$1," ",REPT(" ",90)),{1,91,181},90))&" "," "&$A$1:$A$10&" ")),{1;1;1})
=
(LEN($C$1)-LEN(SUBSTITUTE($C$1," ",""))+1)
,ROW($A$1:$A$10)),ROWS(D$1:D1))),"")

Markmzz

Sorry, I forgot one zero:

=IFERROR(INDEX($A$1:$A$100,
SMALL(IF(MMULT(--ISNUMBER(SEARCH(" "&TRIM(MID(SUBSTITUTE($C$1," ",REPT(" ",90)),{1,91,181},90))&" "," "&$A$1:$A$10
0&" ")),{1;1;1})=
(LEN($C$1)-LEN(SUBSTITUTE($C$1," ",""))+1),ROW($A$1:$A$10
0)),ROWS(D$1:D1))),"")

Markmzz
 
Last edited:
Upvote 0

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
But if I were to say the word order wasn't important, is there an easy fix?
The adjustment to my formula would be:

Excel Workbook
ABC
1TitlesJourney Earth
2All Passion SpentA Journey from Earth to Mars
3Journey's End: EarthEarth Beyond the Zen Journey
4A Journey from Earth to MarsJourney to the Center of the Earth
5Antic HayMy Earth Journey
6Earth Beyond the Zen Journey
7Journey to the Center of the Earth
8Butter In a Lordly Dish
9By Grand Central Station I Sat Down and Wept
10Carrion Comfort
11The Children of Men
12My Earth Journey
13Journey To The Fire Hearth
14Cabbages and Kings
Search (any order)




Other comment:
I think Mark's suggestion from post#11 also does what you want, but just be aware that if the user subsequently inserts any new row(s) at the top of the worksheet, those formulas will then return incorrect results. The following adjustment (still array-entered) should fix that though if you prefer to use that structure
=IFERROR(INDEX($A$1:$A$100,
SMALL(IF(MMULT(--ISNUMBER(SEARCH(" "&TRIM(MID(SUBSTITUTE($C$1," ",REPT(" ",90)),{1,91,181},90))&" "," "&$A$1:$A$100&" ")),{1;1;1})=
(LEN($C$1)-LEN(SUBSTITUTE($C$1," ",""))+1),ROW($A$1:$A$100)-ROW($A$1)+1),ROWS(D$1:D1))),"")
 
Upvote 0
Other comment:
I think Mark's suggestion from post#11 also does what you want, but just be aware that if the user subsequently inserts any new row(s) at the top of the worksheet, those formulas will then return incorrect results. The following adjustment (still array-entered) should fix that though if you prefer to use that structure
=IFERROR(INDEX($A$1:$A$100,
SMALL(IF(MMULT(--ISNUMBER(SEARCH(" "&TRIM(MID(SUBSTITUTE($C$1," ",REPT(" ",90)),{1,91,181},90))&" "," "&$A$1:$A$100&" ")),{1;1;1})=
(LEN($C$1)-LEN(SUBSTITUTE($C$1," ",""))+1),ROW($A$1:$A$100)-ROW($A$1)+1),ROWS(D$1:D1))),"")

Hi Peter!

You are right and thank you for the help with my suggestion.

Markmzz
 
Upvote 0
The adjustment to my formula would be:
Spreadsheet Formulas
CellFormula
C2=IFERROR(INDEX(A$1:A$100,AGGREGATE(15,6,(ROW(A$1:A$100)-ROW(A$1)+1)/(ISNUMBER(SEARCH(" "&SUBSTITUTE(C$1," "," * ")&" "," "&SUBSTITUTE(A$1:A$100," "," ")&" "))
+ISNUMBER(SEARCH(MID(C$1&" * "&C$1,FIND(" ",C$1),LEN(C$1)+4)," "&SUBSTITUTE(A$1:A$100," "," ")&" ")))
,ROWS(C$2:C2))
)
,"")

<tbody>
</tbody>

<tbody>
</tbody>

This is so good (thanks for all answers everyone)

I've adjusted your formula slightly as follows:
CellFormula
C2=IFERROR(INDEX(A$1:A$100,AGGREGATE(15,6,(ROW(A$1:A$100)-ROW(A$1)+1)/(ISNUMBER(SEARCH(SUBSTITUTE(C$1," ","*"),SUBSTITUTE(A$1:A$100," "," ")))
+ISNUMBER(SEARCH(MID(C$1&" * "&C$1,FIND(" ",C$1),LEN(C$1)+4)," "&SUBSTITUTE(A$1:A$100," "," ")&" "))),ROWS(C$2:C2))),"")

<tbody>
</tbody>
<strike></strike>
This then works for partial matches and eliminates issues with punctuation.

But there is a bug in there somewhere, and it is this: When I reverse the words then partial matches don't work, and also if I search "Mars Journey" it will return "A Journey from Earth to Mars", but if I search "Mars to" it doesn't return it. "To Mars" is fine, but not backwards. In other words, if the words are next to each other in the title, the backward search doesn't work.

To be honest, it's so picky that it wouldn't bother me if I kept it as is, it will work for 90% of queries, I can just ask the users to mix the words if they don't get the result they're expecting. But, I've tried tinkering with the formulas bit by bit and I can't figure it out. And I guess it would be nice if it were perfect.

Either way, thanks all again; it's brilliant!
 
Last edited:
Upvote 0
I'm guessing that you have edited the formula incorrectly, but before I go searching for that, do you have any comments on the following?

If you are changing to partial matches, and you are searching for "To Mars", does that mean you happy if the search returns "A Biography of Marshall Patton" which matches the text strings but has nothing to do with the two words being searched for.
 
Last edited:
Upvote 0
Hi Peter, yes, I'm happy with partial matches. That's because almost any search of two words will drastically reduce the options and make the book much easier to find (there are a lot more than a hundred books in reality). The user would have to use his common sense and not search for "and the" or other words that are likely to be in many titles.

But the reason its better to have partial matches allowed is because the user may not be sure whether the book is called "The talented Mr Ripley", "The talent of Mr Ripply" or "Mr Riply is Talented" So a search for "Rip Talent" will return all the options. If it returns "Talent is dead: RIP" as well, then so be it.

Thanks ever so much: I appreciate everyone's help and I have been trying to not bother people by trying to work it through myself. But I'm a bit thick at things like this.
 
Last edited:
Upvote 0
Hi Damo71,

I think that my suggestion can help you. Look at this:

Array Formula - use Ctrl+Shift+Enter to enter the formula


=IFERROR(INDEX($A$1:$A$100,
SMALL(IF(MMULT(--ISNUMBER(SEARCH(" "&TRIM(MID(SUBSTITUTE($C$1," ",REPT(" ",90)),{1,91},90))&" "," "&$A$1:$A$100&" ")),{1;1})=
(LEN($C$1)-LEN(SUBSTITUTE($C$1," ",""))+1),ROW($A$1:$A$100)-ROW($A$1)+1),ROWS(D$1:D1))),"")


ABCDE
1All Passion SpentMars toA Journey from Earth to Mars
2Journey's End: Earth
3A Journey from Earth to Mars
4Antic Hay
5Earth Beyond the Zen Journey
6Journey to the Center of the Earth
7Butter In a Lordly Dish
8By Grand Central Station I Sat Down and Wept
9Carrion Comfort
10The Children of Men
11My Earth Journey
12Journey To The Fire Hearth
13Cabbages and Kings
14
******************************************************************************************************

<tbody>
</tbody>

Markmzz
 
Upvote 0
Hi Peter, yes, I'm happy with partial matches.
In that case my formula gets reduced a reasonable amount.

Excel Workbook
ABC
1TitlesJourney Earth
2All Passion SpentJourney's End: Earth
3Journey's End: EarthA Journey from Earth to Mars
4A Journey from Earth to MarsEarth Beyond the Zen Journey
5Antic HayJourney to the Center of the Earth
6Earth Beyond the Zen JourneyMy Earthly Journey
7Journey to the Center of the EarthJourney To The Fire Hearth
8Butter In a Lordly Dish
9By Grand Central Station I Sat Down and Wept
10Carrion Comfort
11The Children of Men
12My Earthly Journey
13Journey To The Fire Hearth
14Cabbages and Kings
Search (any order) (2)
 
Upvote 0
Actually, if it is possible that the lists of titles could include one where the 2 strings are found in both orders (eg "Earth Journey & Earth Experiences") then my previous formula could produces results with none of the required text strings in it. :eek:

This modification I think will prevent that happening.

Excel Workbook
ABC
1TitlesJourney Earth
2All Passion SpentJourney's End: Earth
3Journey's End: EarthA Journey from Earth to Mars
4A Journey from Earth to MarsEarth Journey & Earth Experiences
5Antic HayJourney to the Center of the Earth
6Earth Journey & Earth ExperiencesMy Earthly Journey
7Journey to the Center of the EarthJourney To The Fire Hearth
8Butter In a Lordly Dish
9By Grand Central Station I Sat Down and Wept
10Carrion Comfort
11The Children of Men
12My Earthly Journey
13Journey To The Fire Hearth
14Cabbages and Kings
Search (any order) (2)
 
Upvote 0
Another way.

Here is my suggestion with Peter's example:


ABCDE
1All Passion SpentJourney EarthA Journey from Earth to Mars
2Journey's End: EarthEarth Beyond the Zen Journey
3A Journey from Earth to MarsJourney to the Center of the Earth
4Antic HayMy Earth Journey
5Earth Beyond the Zen Journey
6Journey to the Center of the Earth
7Butter In a Lordly Dish
8By Grand Central Station I Sat Down and Wept
9Carrion Comfort
10The Children of Men
11My Earth Journey
12Journey To The Fire Hearth
13Cabbages and Kings
14
*********************************************************************************************************

<tbody>
</tbody>

Markmzz
 
Upvote 0

Forum statistics

Threads
1,214,965
Messages
6,122,499
Members
449,089
Latest member
Raviguru

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