Using Countif with a wide range of data

wangaa11

New Member
Joined
Feb 28, 2020
Messages
43
Office Version
  1. 2016
Platform
  1. Windows
Hello, I am trying to use the countifs fomula to find out the number of times "yes" appears per colour see example below. I would upload an example but for some reason it never lets me.

In this example I want to count the number of times there is a "Yes" with the colour red. The answer should be 7. I have over 20 columns of data and I am wondering if there is a better formula to use outside of =countifs(A1:A7,"Red",B1:B7,"Yes")+countifs(A1:A7,"Red",C1:C7,"Yes")+countifs(A1:A7,"Red",D1:D7,"Yes")+ so on and so on.

Any help is greatly appreciated

ABCDEFG
1RedYesNoYesYesYesYes
2BlueNoYesN/AYesN/ANo
3RedN/ANoN/AYesN/ANo
4RedYesN/ANoNoN/ANo
5GreenYesN/ANoNoN/AN/A
6GreenYesN/ANoNoN/AN/A
7BlueN/ANoYesNoNoN/A
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
How about
+Fluff v2.xlsm
ABCDEFGHIJ
1ABCDEFG
2RedYesNoYesYesYesYesRed7
3BlueNoYesN/AYesN/ANoBlue3
4RedN/ANoN/AYesN/ANoGreen2
5RedYesN/ANoNoN/ANo
6GreenYesN/ANoNoN/AN/A
7GreenYesN/ANoNoN/AN/A
8BlueN/ANoYesNoNoN/A
List
Cell Formulas
RangeFormula
J2:J4J2=SUMPRODUCT(($A$2:$A$8=I2)*($B$2:$G$8="Yes"))
 
Upvote 0
How about
+Fluff v2.xlsm
ABCDEFGHIJ
1ABCDEFG
2RedYesNoYesYesYesYesRed7
3BlueNoYesN/AYesN/ANoBlue3
4RedN/ANoN/AYesN/ANoGreen2
5RedYesN/ANoNoN/ANo
6GreenYesN/ANoNoN/AN/A
7GreenYesN/ANoNoN/AN/A
8BlueN/ANoYesNoNoN/A
List
Cell Formulas
RangeFormula
J2:J4J2=SUMPRODUCT(($A$2:$A$8=I2)*($B$2:$G$8="Yes"))
That is worked thank you so much
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,650
Messages
6,120,734
Members
448,987
Latest member
marion_davis

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