Count number of times a specific text appears in a string & range

Rav_Singh

New Member
Joined
Jun 29, 2019
Messages
25
I hope someone can help with this problem I am failing to find a solution for.

I wish to count the number of times a specific text value appears in a range. The text itself will often be part of a string which will contain other information.

Below is an example of the issue I am encountering... In this instance but not exclusive I am trying to locate the number of times 'Accounting' appears in a range.

Example (value):
[Cell B1] Accounting

Example (Range):
[Cell A1] Accounting
[Cell A2] Accounting OR Business+services
[Cell A3] Accounts OR Accounting

Solution:
[Cell C1] 3

I had hoped the below formulas would work but alas these only return 1 instead of 3.

=SUMPRODUCT((--EXACT(B1,A1:A3))) = 1
=COUNTIF(A1:A3,B1) = 1

* If possible I would appreciate a solution which includes the cell (in this case 'B1') in the formula rather than 'Accounting' as this solution is intended to incorporate other values.

As always any feedback will be greatly received and appreciated.
 
Last edited:

kweaver

Well-known Member
Joined
May 8, 2018
Messages
735
Have you tried this in C1 with the word you're searching for in B1:

Code:
=COUNTIF(A1:A100,"*"&B1&"*")
 

Rav_Singh

New Member
Joined
Jun 29, 2019
Messages
25
Thank you both for taking time out to post your input.

I was worried this solution was too good to be true and alas it has proved so.

I have updated the scenario below to provide the complexity of the issue.

Example (value):
[Cell B1] Accounting

Example (Range):
[Cell A1] Accounting
[Cell A2] Accounting OR Business+services
[Cell A3] Accounts OR Accounting
[Cell A4] Accounting+Department *(Do not count this in the solution)
[Cell A5] Director+of+Accounting *(Do not count this in the solution)

Solution:
[Cell C1] 3

Any further input will be greatly received.
 
Last edited:

kweaver

Well-known Member
Joined
May 8, 2018
Messages
735
Are you saying that if there's a * in the cell, not to consider this in the count?
 

Rav_Singh

New Member
Joined
Jun 29, 2019
Messages
25
To clarify '*(Do not count this in the solution) ' is not part of the string/range. This was my attempt to indicate that the text in cells A4 & A5 should not be calculated in the solution.

Thanks.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,317
Office Version
365
Platform
Windows
Judging by post#4
Maybe

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="color: #333333;;">Accounting</td><td style=";">Accounting</td><td style="text-align: right;;">3</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style="color: #333333;;">Accounting OR Business+services</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="color: #333333;;">Accounts OR Accounting</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">Accounting+Department</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style=";">Director+of+Accounting</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:5.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Norfolk</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">C1</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--ISNUMBER(<font color="Red">FIND(<font color="Green">" "&B1&" "," "&A1:A5&" "</font>)</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 

Rav_Singh

New Member
Joined
Jun 29, 2019
Messages
25
Job done! - Take a bow.

I always say this on here but many thanks for all contributors taking time out to assist with my Excel issues!

Judging by post#4
Maybe

ABC
1AccountingAccounting3
2Accounting OR Business+services
3Accounts OR Accounting
4Accounting+Department
5Director+of+Accounting

<colgroup><col style="width: 25pxpx"><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Norfolk

Worksheet Formulas
CellFormula
C1=SUMPRODUCT(--ISNUMBER(FIND(" "&B1&" "," "&A1:A5&" ")))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,317
Office Version
365
Platform
Windows
Glad we could help & thanks for the feedback
 

Forum statistics

Threads
1,082,295
Messages
5,364,359
Members
400,792
Latest member
Dxmiian

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