Word Count

LtVVaughn

New Member
Joined
Sep 7, 2006
Messages
17
I am trying to find the number of times specific words occur in a column. For instance, I am serching for "visit" and "call" (not case sensitive) within a column. These words may occur more than once in a particular cell of the column and I need to count each time these words occur, not a count per word, but count the times both words occur in cells in the column.

Thanks in advance!
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
Code:
=SUM(COUNTIF(A1:B8,"*visit*"),COUNTIF(A1:B8,"*call*"))

Snag_1a5d7d52.png
 
Upvote 0
That works for 10 of the 13 occurrences. I think is is not counting 3 of the occurrences because there are more that one occurrence in three of the cells. Is there any way to fix that?
 
Upvote 0
Try:

Book1 (version 1).xlsb
ABCD
1ListWordCount
2runcall8
3walkvisit6
4visit
5call
6visit
7call on me
8visit and call
9call and visit
10jump and call
11hop and jump
12visit me, visit her
13call, call, call
14end
Sheet8
Cell Formulas
RangeFormula
D2:D3D2=SUMPRODUCT(LEN(A$2:A$14)-LEN(SUBSTITUTE(A$2:A$14,C2,"")))/LEN(C2)


You can combine the 2 formulas if you want to get a total count.
 
Upvote 0
what about
Option
Custom Rib.xlsm
ABCD
1call me befre your visit don’t visit me befre call Mevisit No.call No.Total
2visit visit call call call459
Sheet5
Cell Formulas
RangeFormula
B2B2=(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,$A$1:$A$2),"visit",""))) / LEN("visit")
C2C2=(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,$A$1:$A$2),"call",""))) / LEN("call")
D2D2=(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,$A$1:$A$2),"visit",""))) / LEN("visit")+(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,$A$1:$A$2),"call",""))) / LEN("call")
 
Upvote 0
=(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,$A$1:$A$2),"visit",""))) / LEN("visit")+(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,$A$1:$A$2),"call",""))) / LEN("call")

I tried the above formula and it worked! ! ! The exception being that it is case sensitive. It did not read one word because the first letter was capitalized. Is there a way to remedy that?
 
Upvote 0
You can update the above formula by adding LOWER around the ranges in the SUBSTITUTE, like this:

Excel Formula:
=(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,LOWER($A$1:$A$2)),"visit",""))) / LEN("visit")+(LEN(TEXTJOIN(" ",TRUE,$A$1:$A$2)) - LEN(SUBSTITUTE(TEXTJOIN(" ",TRUE,LOWER($A$1:$A$2)),"call",""))) / LEN("call")

But I was working on an alternate method (also case-insensitive) and is shorter:

Excel Formula:
=SUM(COUNTIF(A2:A14,"*"&REPT({"call";"visit"}&"*",{1,2,3,4,5})))

This should work as long as the number of instances in each cell is no more than 5.
 
Upvote 0
=SUM(COUNTIF(A2:A14,"*"&REPT({"call";"visit"}&"*",{1,2,3,4,5})))
The above worked perfectly! Thanks to all of you! ! !
 
Upvote 0
Book1
ABCD
1Call me before your visit don’t visit me before call MevisitcallTotal
2Visit visit call call call459
Sheet1
Cell Formulas
RangeFormula
B2:C2B2=(LEN(UPPER(TEXTJOIN(" ",TRUE,$A$1:$A$2))) - LEN(SUBSTITUTE(UPPER(TEXTJOIN(" ",TRUE,$A$1:$A$2)),UPPER(B1),""))) / LEN(UPPER(B1))
D2D2=(LEN(UPPER(TEXTJOIN(" ",TRUE,$A$1:$A$2))) - LEN(SUBSTITUTE(UPPER(TEXTJOIN(" ",TRUE,$A$1:$A$2)),UPPER(B1),""))) / LEN(UPPER(B1))+(LEN(UPPER(TEXTJOIN(" ",TRUE,$A$1:$A$2))) - LEN(SUBSTITUTE(UPPER(TEXTJOIN(" ",TRUE,$A$1:$A$2)),UPPER(C1),""))) / LEN(UPPER(C1))
 
Upvote 0

Forum statistics

Threads
1,213,567
Messages
6,114,344
Members
448,570
Latest member
rik81h

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