Counting Individual Numbers Within Cells

rkoehler58

New Member
Joined
Sep 18, 2014
Messages
22
I have a sheet which contains the following:

Column A Column B Column C Column D
Safe 4, 10 Hot 3
Safe 1, 3, 5 Hot 2, 5
Safe 13 Hot 7

Columns B and D may contain multiple entries within a cell.

I am trying to develop a formula to calculate the total number of entries for "Safe and "Hot".

In my example, the number of entries for "Safe" will be 6, while the number of entries for "Hot" would be 4.

Can anyone suggest a way to do this?
 

Some videos you may like

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.

Snakehips

Well-known Member
Joined
May 17, 2009
Messages
5,059
Office Version
  1. 2013
Platform
  1. Windows
rkoehler,

If the entries will always be separated by a comma then maybe something like.....
<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: center;background-color: #BFBFBF;;">Safe</td><td style="text-align: center;background-color: #BFBFBF;;">Hot</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Safe</td><td style=";">4, 10</td><td style=";">Hot</td><td style=";">3</td><td style="text-align: center;background-color: #BFBFBF;;">9</td><td style="text-align: center;background-color: #BFBFBF;;">7</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Safe</td><td style=";">1,3, 5</td><td style=";">Hot</td><td style=";">2, 5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Safe</td><td style=";">13</td><td style=";">Hot</td><td style=";">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Safe</td><td style=";">1, 2, 3</td><td style=";">Hot</td><td style=";">1, 2, 3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet6</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><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: #E0E0F0;color: #161120">E2</th><td style="text-align:left">{=SUM(<font color="Blue">LEN(<font color="Red">B2:B20</font>)-LEN(<font color="Red">SUBSTITUTE(<font color="Green">B2:B20,",",""</font>)</font>)+IF(<font color="Red">B2:B20="",0,1</font>)</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">F2</th><td style="text-align:left">{=SUM(<font color="Blue">LEN(<font color="Red">D2:D20</font>)-LEN(<font color="Red">SUBSTITUTE(<font color="Green">D2:D20,",",""</font>)</font>)+IF(<font color="Red">D2:D20="",0,1</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
Hope that helps.
 
Last edited:

rkoehler58

New Member
Joined
Sep 18, 2014
Messages
22
rkoehler,

If the entries will always be separated by a comma then maybe something like.....
Excel 2007
ABCDEF
1SafeHot
2Safe4, 10Hot397
3Safe1,3, 5Hot2, 5
4Safe13Hot7
5Safe1, 2, 3Hot1, 2, 3
6

<colgroup><col><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet6

Array Formulas
CellFormula
E2{=SUM(LEN(B2:B20)-LEN(SUBSTITUTE(B2:B20,",",""))+IF(B2:B20="",0,1))}
F2{=SUM(LEN(D2:D20)-LEN(SUBSTITUTE(D2:D20,",",""))+IF(D2:D20="",0,1))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

<tbody>
</tbody>


Hope that helps.

That works great. Thanks for your help.
 

Watch MrExcel Video

Forum statistics

Threads
1,108,510
Messages
5,523,318
Members
409,511
Latest member
hitesh222002

This Week's Hot Topics

Top