Help with conditional counting

geddiknight

New Member
Joined
Jun 26, 2007
Messages
18
Hey. Im looking to count the number of times in a table where two cells in a row have certain properties, for example:

i want to know how many times column 4 has "High" written it when (and only when) column 6 has "Black" in it.

could this be done as a formula or would i have to use VBA? if the latter, could someone help me with the code to write - im just learning VBA.

thanks

chris
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Good afternoon geddiknight

Assuming that your column 4 is D and column 6 is F, then something like this should suffice :

=SUMPRODUCT(--(D1:D100="High"),--(F1:F100="Black"))

HTH

DominicB
 
Upvote 0
Hi VogII and DominicB.

I'm still trying to learn about sumproduct - can you explain please how this works, and what the -- do ?

I understand how basic sumproducts work, but not this one.

Cheers !
 
Upvote 0
In addition to that, I'll show how it evaluates by showing it on the spreadsheet (on a smaller scale).

Columns I and J show the TRUE/FALSE values for each condition for Columns D and F. Columns K and L show the TRUE/FALSE values coerced to 1 and 0 respectively. Each row is multiplied so 1x1=1 but if either condition is FALSE it will return 0 as anything multiplied by 0 is 0. These are all then summed giving you the count.
Excel Workbook
DEFGHIJKLM
1LOGICAL VALUESCOERCED VALUESPRODUCT
2HighBlackTRUETRUE111
3LowBlackFALSETRUE010
4MediumBrownFALSEFALSE000
5LowBlackFALSETRUE010
6HighBlackTRUETRUE111
7SUM:2
Sheet
 
Upvote 0

Forum statistics

Threads
1,215,506
Messages
6,125,193
Members
449,213
Latest member
Kirbito

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