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!
 

Ron Coderre

MrExcel MVP
Joined
Jan 14, 2009
Messages
2,306
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:

Raymond1

New Member
Joined
Dec 1, 2015
Messages
36
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
 

Ron Coderre

MrExcel MVP
Joined
Jan 14, 2009
Messages
2,306
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
 

Forum statistics

Threads
1,082,300
Messages
5,364,384
Members
400,796
Latest member
vrcdesktop

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top