how can I count number of hits in a cell from a keyword list ?

Raymond1

New Member
Joined
Dec 1, 2015
Messages
36
I was able to obtain TRUE or FALSE from multiple keywords using:
=OR(ISNUMBER(SEARCH(H$5:H$12,D5)))

but how can I return the # of hits?

Thanks for your assistance!
 

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).
With these text values in A3:A6
Code:
My Alpha Romeo
Does charlie own an alpha romeo?
Can you foxtrot in an alpha romeao while playing golf?
No matches here

And this list of text to match in H5:H12 (Notice they're all UPPER CASE)
Code:
ALPHA
BRAVO
CHARLIE
DELTA
ECHO
FOXTROT
GOLF
HOTEL

This regular formula, copied down, returns the number of list items contained in each of the text values:
Code:
B3: =SUMPRODUCT((LEN(A3)-LEN(SUBSTITUTE(UPPER(A3),$H$5:$H$12,"")))/LEN($H$5:$H$12))

In the above example, these are the results:
Code:
My Alpha Romeo                                                1
Does charlie own an alpha romeo?                              2
Can you foxtrot in an alpha romeao while playing golf?        3
No matches here                                               0

Note: If you don't care if the same list word appears in your text more than once,
you might be able to use this much simpler formula:
Code:
A3: =SUMPRODUCT(COUNTIF(A3,"*"&$H$5:$H$12&"*"))
Is that something you can work with?
 
Last edited:
Upvote 0
Hi,

Thanks for your reply!

The formula generally works with 2 exceptions:

1 - if I use the word "IMPACT*D" it would not pick up the work 'IMPACT'
2 - the bit about the UPPER is curious...is there a way to avoid the uppercase in the formula?

Thanks again!

Ray
 
Upvote 0
1) The SUBSTITUTE function is case-sensitive. The typical approach to accommodating that is to UPPERCASE or LOWERCASE everything.
2) From a matching perspective, "IMPACT*" would match text beginning with IMPACT. Using "IMPACT*D" would match text beginning with "IMPACT" and ending with "D"...including "IMPACT WAS PROFOUND". You might find it easier to list each item.

Do you need to know the count of occurrences of search terms found in text sample? Or do you only need to count each search term once even if it occurs multiple times in the text?

Also....this is from my formula stash (it might be helpful)
This formula returs TRUE if cell A1 equals any list items
B1: =OR(A1={"apple","banana","cherry"})

This formula returns the count of list items that are contained in A1
B1: =SUMPRODUCT(COUNTIF(A1,"*"&{"apple","banana","cherry"}&"*"))
B1: =SUMPRODUCT(COUNTIF(A1,"*"&rngList&"*"))

This function checks if A1 begins with, or ends with, a list item
B1: =SUMPRODUCT(COUNTIF(A1,{"*",""}&{"apple","banana","cherry"}&{"","*"}))
B1: =SUMPRODUCT(COUNTIF(A1,{"*",""}&rngList&{"","*"}))

Other alternatives:
This case-insensitive formula checks if the text contains BOTH "quick" and "fox"
B1: =SUMPRODUCT(COUNTIF(A1,"*"&{"quick","fox"}&"*"))=2
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,219
Members
452,619
Latest member
Shiv1198

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