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

Rav_Singh

New Member
Joined
Jun 29, 2019
Messages
28
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:

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
Have you tried this in C1 with the word you're searching for in B1:

Code:
=COUNTIF(A1:A100,"*"&B1&"*")
 
Upvote 0
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:
Upvote 0
Are you saying that if there's a * in the cell, not to consider this in the count?
 
Upvote 0
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.
 
Upvote 0
Judging by post#4
Maybe


Book1
ABC
1AccountingAccounting3
2Accounting OR Business+services
3Accounts OR Accounting
4Accounting+Department
5Director+of+Accounting
Norfolk
Cell Formulas
RangeFormula
C1=SUMPRODUCT(--ISNUMBER(FIND(" "&B1&" "," "&A1:A5&" ")))
 
Upvote 0
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>
 
Upvote 0
Glad we could help & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,213,486
Messages
6,113,932
Members
448,533
Latest member
thietbibeboiwasaco

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