search for multiple keywords in a cell and return positive resuly when ALL are present

dori2o

Board Regular
Joined
Apr 7, 2016
Messages
72
I'm creating a quiz sheet in excel where the user inputs their answer into a cell. (i.e Cell F5)

The idea is that if they enter their answer into the answer cell the cell in the next column of that row will show a 'Tick' (uppercase P in windings font) if the answer is corect. At all other times the cell shows a 'cross' (uppercase O in windings).

Once all questions have been answered and all are correct they can submit the worksheet to an email address for the sheets to be verified and a winner chosen at random.

In order to get the tick in the cell the answer must contain certain keywords that are essential to the answer. i.e. the answer cannot be correct without these keywords.

I'm using =IF(SUMPRODUCT(--ISNUMBER(SEARCH(Y18:Y20,F5))),"P","O") to check for keywords in cell F5.

However, currently the formula returns a positive result even if there is only 1 word from the keywords list (held in range Y18:Y20) within the answer.

How would I update the formula so that all of the words in the list have to present within the text string before a positive result is returned.

Also can anyone confirm that having blank cells in the keywords list will have no effect on the answer, and if so how would I rectify this?

Many Thanks in advance.
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
Try:
Code:
=IF(SUMPRODUCT(--(Y18:Y20<>"")*ISNUMBER(SEARCH(Y18:Y20,F5)))=ROWS(Y18:Y20),"P","O")
EDITED to include case where list (Y18:Y20) contains blank cells.
 
Last edited:
Upvote 0
Ignore post #2 . Testing shows that formula fails when there are blank cells in the list. I have to go offline now, hopefully someone else will provide a blanks-tolerant solution.:)
 
Upvote 0
Lightly tested, but I think this handles blank cells in your keyword list.
Code:
=IF(SUMPRODUCT(--ISNUMBER(SEARCH(Y18:Y20,F5))*(Y18:Y20<>""))=COUNTA(Y18:Y20),"P","O")
 
Upvote 0
Lightly tested, but I think this handles blank cells in your keyword list.
Code:
=IF(SUMPRODUCT(--ISNUMBER(SEARCH(Y18:Y20,F5))*(Y18:Y20<>""))=COUNTA(Y18:Y20),"P","O")
Works so long as one of the words in Y18:Y20 is not embedded within a longer word. For example...

Y18: one
Y19: two
Y20: three

F5: two plus three (I'm done).
 
Last edited:
Upvote 0
Here is a UDF (user defined function) that will correctly count words from the list only when they stand-alone (that is, when they are not embedded within other words) no matter what punctuations marks or spaces are next to them...
Code:
[table="width: 500"]
[tr]
	[td]Function MatchAll(Answer As String, WordList As Range) As String
  Dim R As Long, Cnt As Long, WordsCnt As Long, Words As Variant
  Words = Evaluate(Replace("IF(@="""","""",UPPER(@))", "@", WordList.Address))
  For R = 1 To UBound(Words)
    If Len(Words(R, 1)) Then
      WordsCnt = WordsCnt + 1
      If " " & UCase(Answer) & " " Like "*[!A-Z0-9]" & Words(R, 1) & "[!A-Z0-9]*" Then Cnt = Cnt + 1
    End If
  Next
  If Cnt = WordsCnt Then MatchAll = "P" Else MatchAll = "O"
End Function[/td]
[/tr]
[/table]

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use MatchAll just like it was a built-in Excel function. For example,

=MatchAll(F5,Y18:Y20)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0
Hi,

A formula version...and it solves the problem posted by Rick Rothstein in #5

Ctrl+Shift+Enter NOT just Enter

=IF(AND(Y18:Y20<>"",EXACT(TRIM(MID($F$5,IF(SEARCH(Y18,$F$5)-1=0,1,SEARCH(Y18,$F$5)-1),LEN(Y18)+1)),Y18),EXACT(TRIM(MID($F$5,IF(SEARCH(Y19,$F$5)-1=0,1,SEARCH(Y19,$F$5)-1),LEN(Y19)+1)),Y19),EXACT(TRIM(MID($F$5,IF(SEARCH(Y20,$F$5)-1=0,1,SEARCH(Y20,$F$5)-1),LEN(Y20)+1)),Y20)),"P","O")
 
Last edited:
Upvote 0
Hi,

A formula version...and it solves the problem posted by Rick Rothstein in #5

Ctrl+Shift+Enter NOT just Enter

=IF(AND(Y18:Y20<>"",EXACT(TRIM(MID($F$5,IF(SEARCH(Y18,$F$5)-1=0,1,SEARCH(Y18,$F$5)-1),LEN(Y18)+1)),Y18),EXACT(TRIM(MID($F$5,IF(SEARCH(Y19,$F$5)-1=0,1,SEARCH(Y19,$F$5)-1),LEN(Y19)+1)),Y19),EXACT(TRIM(MID($F$5,IF(SEARCH(Y20,$F$5)-1=0,1,SEARCH(Y20,$F$5)-1),LEN(Y20)+1)),Y20)),"P","O")
I am not sure there are always going to be 3 words to match for each question. What if there are 10 words that needed to match? Or 20?

Also, I am not so sure your code addresses the possible problem JoeMo raised, namely, a blank cell within the word list in Column Y.
 
Upvote 0
If it is more than 3 words then you are absolutely right , the formula will be long and cumbersome...
 
Upvote 0
Here is one which expects a space between the answers in F5...

=IF(SUMPRODUCT(ISNUMBER(SEARCH(" "&$Y$8:$Y$20&" "," "&F5&" "))+0)=COUNTIFS($Y$8:$Y$20,"?*"),"P","O")

When F5 = one two done x and Y8:Y20 consists of just one, two, and three, this formula will return O.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,178
Members
453,021
Latest member
Justyna P

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