Count Non-Blank Rows

riclop

New Member
Joined
Dec 16, 2008
Messages
10
I have a table like below and I want to count only those rows with an "x" under any of the three column headings (the answer is 3 in this example).

<table border="0" cellpadding="0" cellspacing="0" width="294"><colgroup><col style="mso-width-source:userset;mso-width-alt:3730;width:77pt" width="102"> <col style="width:48pt" span="3" width="64"> </colgroup><tbody><tr style="height:11.25pt" height="15"> <td class="xl25" style="height:11.25pt;width:77pt" height="15" width="102"> <table border="0" cellpadding="0" cellspacing="0" width="294"><colgroup><col style="mso-width-source:userset;mso-width-alt:3730;width:77pt" width="102"> <col style="width:48pt" span="3" width="64"> </colgroup><tbody><tr style="height:11.25pt" height="15"> <td class="xl26" style="height:11.25pt;width:77pt" height="15" width="102">
</td> <td class="xl27" style="width:48pt" width="64">Clean</td> <td class="xl27" style="border-left:none;width:48pt" width="64">Water</td> <td class="xl27" style="border-left:none;width:48pt" width="64">Food</td> </tr> <tr style="height:12.75pt" height="17"> <td class="xl25" style="height:12.75pt" height="17">Dog</td> <td class="xl28" style="border-top:none;border-left:none">
</td> <td class="xl28" style="border-top:none;border-left:none">
</td> <td class="xl28" style="border-top:none;border-left:none">x</td> </tr> <tr style="height:11.25pt" height="15"> <td class="xl25" style="height:11.25pt;border-top:none" height="15">Cat</td> <td class="xl28" style="border-top:none;border-left:none">
</td> <td class="xl28" style="border-top:none;border-left:none">
</td> <td class="xl28" style="border-top:none;border-left:none">
</td> </tr> <tr style="height:11.25pt" height="15"> <td class="xl25" style="height:11.25pt;border-top:none" height="15">Lion</td> <td class="xl28" style="border-top:none;border-left:none">x</td> <td class="xl28" style="border-top:none;border-left:none">x</td> <td class="xl28" style="border-top:none;border-left:none">
</td> </tr> <tr style="height:11.25pt" height="15"> <td class="xl25" style="height:11.25pt;border-top:none" height="15">Bear</td> <td class="xl28" style="border-top:none;border-left:none">x</td> <td class="xl28" style="border-top:none;border-left:none">
</td> <td class="xl28" style="border-top:none;border-left:none">x</td> </tr> </tbody></table></td><td class="xl27" style="width:48pt" width="64">
</td><td class="xl27" style="border-left:none;width:48pt" width="64">
</td><td class="xl27" style="border-left:none;width:48pt" width="64">
</td></tr><tr style="height:12.75pt" height="17"><td class="xl28" style="height:12.75pt" height="17">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td></tr><tr style="height:11.25pt" height="15"><td class="xl28" style="height:11.25pt;border-top:none" height="15">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td></tr><tr style="height:11.25pt" height="15"><td class="xl28" style="height:11.25pt;border-top:none" height="15">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td></tr><tr style="height:11.25pt" height="15"><td class="xl28" style="height:11.25pt;border-top:none" height="15">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td><td class="xl26" style="border-top:none;border-left:none">
</td></tr></tbody></table>Countif won't work as that returns all cell values that have "x", and I want rows. I don't want to add a helper column either. I want answer to be self contained to one cell formula.

I am sure there is an array way of doing this, I just can't figure it out.
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Control+shift+enter, not just enter:

=SUM(IF(MMULT((B2:D5="X")+0,TRANSPOSE(COLUMN(B2:D5)^0))>0,1))

Also, from a suggestion by pgc01 an earlier thread...

=SUM((FREQUENCY(IF(B2:D5="X",ROW(B2:D5)),ROW(B2:D5))>0)+0)
 
Upvote 0
Try:
Excel Workbook
ABCD
1CleanWaterFood
2Dogx
3Cat
4Lionxx
5Bearxx
6
73
Sheet
 
Upvote 0
Thanks for the replies. I figured it out going this route.
<TABLE style="WIDTH: 384pt; BORDER-COLLAPSE: collapse" cellSpacing=0 cellPadding=0 width=512 border=0 x:str><COLGROUP><COL style="WIDTH: 48pt" span=8 width=64><TBODY><TR style="HEIGHT: 11.25pt" height=15><TD class=xl26 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" width=64 height=15></TD><TD class=xl27 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; WIDTH: 48pt; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent" width=64>Clean</TD><TD class=xl27 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext; WIDTH: 48pt; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent" width=64>Water</TD><TD class=xl27 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext; WIDTH: 48pt; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent" width=64>Food</TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width=64></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width=64></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width=64></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width=64></TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height=15>Dog</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height=15>Cat</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height=15>Lion</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height=15>Bear</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent"> </TD><TD class=xl29 style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height=15></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height=17></TD><TD class=xl30 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: #eaeaea" align=right x:fmla="=SUMPRODUCT(--(SUBTOTAL(3,OFFSET(B2:D2,ROW(B2:D5)-ROW(B2),,1))>0))" x:num>3</TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD><TD class=xl25 style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent"></TD></TR></TBODY></TABLE>
=SUMPRODUCT(--(SUBTOTAL(3,OFFSET(B2:D2,ROW(B2:D5)-ROW(B2),,1))>0))
 
Upvote 0
Thanks for the replies. I figured it out going this route.
<table style="WIDTH: 384pt; BORDER-COLLAPSE: collapse" x:str="" width="512" border="0" cellpadding="0" cellspacing="0"><colgroup><col style="WIDTH: 48pt" span="8" width="64"></colgroup><tbody><tr style="HEIGHT: 11.25pt" height="15"><td class="xl26" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" width="64" height="15">
</td><td class="xl27" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; WIDTH: 48pt; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent" width="64">Clean</td><td class="xl27" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext; WIDTH: 48pt; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent" width="64">Water</td><td class="xl27" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext; WIDTH: 48pt; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent" width="64">Food</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width="64">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width="64">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width="64">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; WIDTH: 48pt; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent" width="64">
</td></tr><tr style="HEIGHT: 11.25pt" height="15"><td class="xl28" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height="15">Dog</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td></tr><tr style="HEIGHT: 11.25pt" height="15"><td class="xl28" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height="15">Cat</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td></tr><tr style="HEIGHT: 11.25pt" height="15"><td class="xl28" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height="15">Lion</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td></tr><tr style="HEIGHT: 11.25pt" height="15"><td class="xl28" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext 0.5pt solid; BORDER-BOTTOM: windowtext 0.5pt solid; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height="15">Bear</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">
</td><td class="xl29" style="BORDER-RIGHT: windowtext 0.5pt solid; BORDER-TOP: windowtext; BORDER-LEFT: windowtext; BORDER-BOTTOM: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent">x</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td></tr><tr style="HEIGHT: 11.25pt" height="15"><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; HEIGHT: 11.25pt; BACKGROUND-COLOR: transparent" height="15">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td></tr><tr style="HEIGHT: 12.75pt" height="17"><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; HEIGHT: 12.75pt; BACKGROUND-COLOR: transparent" height="17">
</td><td class="xl30" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: #eaeaea" x:fmla="=SUMPRODUCT(--(SUBTOTAL(3,OFFSET(B2:D2,ROW(B2:D5)-ROW(B2),,1))>0))" x:num="" align="right">3</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td><td class="xl25" style="BORDER-RIGHT: #d4d0c8; BORDER-TOP: #d4d0c8; BORDER-LEFT: #d4d0c8; BORDER-BOTTOM: #d4d0c8; BACKGROUND-COLOR: transparent">
</td></tr></tbody></table>
=SUMPRODUCT(--(SUBTOTAL(3,OFFSET(B2:D2,ROW(B2:D5)-ROW(B2),,1))>0))

That's quite all right as long as additional volatility and all text values are admissible. By the way, thanks for providing feedback.
 
Upvote 0
I have a table like below and I want to count only those rows with an "x" under any of the three column headings (the answer is 3 in this example).

<TABLE cellSpacing=0 cellPadding=0 width=294 border=0><COLGROUP><COL style="WIDTH: 77pt; mso-width-source: userset; mso-width-alt: 3730" width=102><COL style="WIDTH: 48pt" span=3 width=64></COLGROUP><TBODY><TR style="HEIGHT: 11.25pt" height=15><TD class=xl25 style="WIDTH: 77pt; HEIGHT: 11.25pt" width=102 height=15><TABLE cellSpacing=0 cellPadding=0 width=294 border=0><COLGROUP><COL style="WIDTH: 77pt; mso-width-source: userset; mso-width-alt: 3730" width=102><COL style="WIDTH: 48pt" span=3 width=64></COLGROUP><TBODY><TR style="HEIGHT: 11.25pt" height=15><TD class=xl26 style="WIDTH: 77pt; HEIGHT: 11.25pt" width=102 height=15>

</TD><TD class=xl27 style="WIDTH: 48pt" width=64>Clean</TD><TD class=xl27 style="BORDER-LEFT: medium none; WIDTH: 48pt" width=64>Water</TD><TD class=xl27 style="BORDER-LEFT: medium none; WIDTH: 48pt" width=64>Food</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD class=xl25 style="HEIGHT: 12.75pt" height=17>Dog</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">x</TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl25 style="BORDER-TOP: medium none; HEIGHT: 11.25pt" height=15>Cat</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl25 style="BORDER-TOP: medium none; HEIGHT: 11.25pt" height=15>Lion</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">x</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">x</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl25 style="BORDER-TOP: medium none; HEIGHT: 11.25pt" height=15>Bear</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">x</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl28 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">x</TD></TR></TBODY></TABLE></TD><TD class=xl27 style="WIDTH: 48pt" width=64>

</TD><TD class=xl27 style="BORDER-LEFT: medium none; WIDTH: 48pt" width=64>

</TD><TD class=xl27 style="BORDER-LEFT: medium none; WIDTH: 48pt" width=64>

</TD></TR><TR style="HEIGHT: 12.75pt" height=17><TD class=xl28 style="HEIGHT: 12.75pt" height=17>

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-TOP: medium none; HEIGHT: 11.25pt" height=15>

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-TOP: medium none; HEIGHT: 11.25pt" height=15>

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD></TR><TR style="HEIGHT: 11.25pt" height=15><TD class=xl28 style="BORDER-TOP: medium none; HEIGHT: 11.25pt" height=15>

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD><TD class=xl26 style="BORDER-TOP: medium none; BORDER-LEFT: medium none">

</TD></TR></TBODY></TABLE>Countif won't work as that returns all cell values that have "x", and I want rows. I don't want to add a helper column either. I want answer to be self contained to one cell formula.

I am sure there is an array way of doing this, I just can't figure it out.
Try this...

=SUMPRODUCT(--(MMULT(--(B2:D5="X"),{1;1;1})>0))
 
Upvote 0

Forum statistics

Threads
1,214,918
Messages
6,122,243
Members
449,075
Latest member
staticfluids

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