CountIfs formula with multiple conditions

karen2712

New Member
Joined
Feb 24, 2007
Messages
35
Hi

Could someone help me with a formula please. I had it all working correctly but the customer now wants to check for multiple conditions and this is where I'm stuck.

I have a worksheet that contains several thousand rows of data and I want to be able to:

1) check column AI to count all records where the date falls between the dates specified in cells A3 and A4
2) when its found these records I want to be able to check column AJ (which contains a location that a test was taken at) to see if the values match the text in cell B3
3) I then need to check whether any of the values in column AR (test result) match either cells C4, C5 OR C6 and count the number that do. For each individual test type, the test result could be either C4, C5 or C6 - I just need a count of how many of any of these test results it finds for the location and date specified.
4) Finally I need to then find all values in column AL (test type) that match the value in cell D4

I managed to get it working on just one of the conditions in point 3 as you can see from the formula below but I can't work out how to check for either of the other conditions in point 3 as well.

=COUNTIFS('Test Requests & Results DTEX'!$AI$2:$AI$27,">="&$A$3,'Test Requests & Results DTEX'!$AI$2:$AI$27,"<="&$A$4,'Test Requests & Results DTEX'!$AJ$2:$AJ$27,"="&$B$3,'Test Requests & Results DTEX'!$AR$2:$AR$27,"="&'Calcs 2018'!$C$4,'Test Requests & Results DTEX'!$AL$2:$AL$27,"="&$D4)

Unfortunately I'm a bit restricted on what I can use e.g. no VBA as out client's IT department will not allow this.

I'd be really grateful for any help.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Hi,

try this:

=SUMPRODUCT(('Test Requests & Results DTEX'!$AI$2:$AI$27>=$A$3)*('Test Requests & Results DTEX'!$AI$2:$AI$27<=$A$4)*('Test Requests & Results DTEX'!$AJ$2:$AJ$27=$B$3)*(('Test Requests & Results DTEX'!$AR$2:$AR$27='Calcs 2018'!$C$4)+('Test Requests & Results DTEX'!$AR$2:$AR$27='Calcs 2018'!$C$5)+('Test Requests & Results DTEX'!$AR$2:$AR$27='Calcs 2018'!$C$6))*('Test Requests & Results DTEX'!$AL$2:$AL$27=$D4))
 
Upvote 0
Try...

=SUMPRODUCT(COUNTIFS('Test Requests & Results DTEX'!$AI$2:$AI$27,">="&$A$3,'Test Requests & Results DTEX'!$AI$2:$AI$27,"<="&$A$4,'Test Requests & Results DTEX'!$AJ$2:$AJ$27,"="&$B$3,'Test Requests & Results DTEX'!$AR$2:$AR$27,"="&'Calcs 2018'!$C$4:$C$6,'Test Requests & Results DTEX'!$AL$2:$AL$27,"="&$D4))
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,312
Members
452,634
Latest member
cpostell

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