Excel Formula to Count a Specific Value in a Range with Cells Containing Multiple Values

NorthbyNorthwest

Board Regular
Joined
Oct 27, 2013
Messages
173
Office Version
  1. 365
Hi, everyone. Can someone help me with an Excel count formula which would count the number of times a value appears in a 4 column by 4 row range? Note: I'm excluding header row. Cells can contain a single value, multiple values separated by a comma, or no value. In the example table I want to count how many 202 values appears. The formula I’m using only counts the first value in each cell.

I'm not sure if these values are numbers or text. When I select two cells, both with a single number in them, they will sum in bottom right corner. However, if I select a cell with a single number and a cell with two numbers, the number do not sum. So, I guess they are text. Also, if these are text values, would the formula be different if a value were four characters vice three? Say, "2022."

201, 202301
202, 317, 411
200, 202, 213202
301, 305119, 202, 207
 
Both what i gave a @Fluff gave produce 5 for me.
Agreed, although they could different results depending on what the actual data is.
Fluff.xlsm
ABCDEFG
1
2201, 20230120256
3202, 317, 41156
4200, 202, 213202
51202301, 305119, 202, 207
Lists
Cell Formulas
RangeFormula
F2F2=LET(a,TRIM(TEXTSPLIT(TEXTJOIN(",",,A2:C5),,",")),ROWS(FILTER(a,a="202")))
G2G2=(LEN(TEXTJOIN(",",TRUE,A2:C5))-LEN(SUBSTITUTE(TEXTJOIN(",",TRUE,A2:C5),"202,","")))/LEN("202,")
F3F3=LET(a,TRIM(TEXTSPLIT(TEXTJOIN(",",,A2:C5),,",")),ROWS(FILTER(a,a=E2&"")))
G3G3=(LEN(TEXTJOIN(",",TRUE,A2:C5))-LEN(SUBSTITUTE(TEXTJOIN(",",TRUE,A2:C5),E2&",","")))/LEN(E2&",")
 
Upvote 0
Solution

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Both what i gave a @Fluff gave produce 5 for me.
No doubt. I was not arriving at right answer when I plugged formula in Excel. But then you explained how the formula worked. So, I started counting manually based on your explanation. And, found I was getting close to answer. So, it was clear to me that I wasn't fully understanding. Thanks, again.
 
Upvote 0
Good point. I had thought of that but not at the start of the number stupidly. Easily fixed mind.
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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