ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   How to count specific letters in range of cells? (https://www.excelbanter.com/excel-discussion-misc-queries/147647-how-count-specific-letters-range-cells.html)

Renee R.[_2_]

How to count specific letters in range of cells?
 
I am looking for a formula to count the number of R's in a range.
=countif(a1:a3,"*R*")... is only giving me 2 - one for each cell there is an
"R"... not 5 for the total number of R's. I need a formula to give me that
"total" - 5 number. Any ideas????

A1 = BETH PAGEL (zero R's)
A2 = BARRY GUNTHER (3 R's)
A3 = RANDY ROST (2 R's)

Rick Rothstein \(MVP - VB\)

How to count specific letters in range of cells?
 
I am looking for a formula to count the number of R's in a range.
=countif(a1:a3,"*R*")... is only giving me 2 - one for each cell there is
an
"R"... not 5 for the total number of R's. I need a formula to give me
that
"total" - 5 number. Any ideas????

A1 = BETH PAGEL (zero R's)
A2 = BARRY GUNTHER (3 R's)
A3 = RANDY ROST (2 R's)


Off the top of my head, this formula should work...

=SUMPRODUCT(LEN((A1:A3))-LEN(SUBSTITUTE((A1:A3),"R","")))

Rick


Rick Rothstein \(MVP - VB\)

How to count specific letters in range of cells?
 
I am looking for a formula to count the number of R's in a range.
=countif(a1:a3,"*R*")... is only giving me 2 - one for each cell there is
an
"R"... not 5 for the total number of R's. I need a formula to give me
that
"total" - 5 number. Any ideas????

A1 = BETH PAGEL (zero R's)
A2 = BARRY GUNTHER (3 R's)
A3 = RANDY ROST (2 R's)


Off the top of my head, this formula should work...

=SUMPRODUCT(LEN((A1:A3))-LEN(SUBSTITUTE((A1:A3),"R","")))


By the way, the above is case-sensitive. If you need a case insensitive
formula, try this one...

=SUMPRODUCT(LEN((A1:A3))-LEN(SUBSTITUTE((A1:A3),{"r","R"},"")))

Rick


Renee R.[_2_]

How to count specific letters in range of cells?
 

Rick that worked perfectly! Thank you. Renee


All times are GMT +1. The time now is 05:11 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com