Array formula returning wrong results

Lunchowl

New Member
Joined
May 24, 2021
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Hello,

I have a COUNTIF formula that contains an array that isn't working for me. The problem seems to be in the 'does not' (<>) section of the formula. The formula always returns results, but the count is incorrect.

I've anonymised the code below - so hopefully still understandable. The A2 at the end is the username in Sheet2 R:R.

Excel Formula:
=COUNTIF('Sheet2'!G:G,"Condition 1",'Sheet2'!I:I,{"<>ConditionA","<>ConditionB","<>ConditionC","<>ConditionD","<>ConditionE","<>ConditionF","<>ConditionG"},'Sheet2'!N:N,"Condition 2",'Sheet2'!O:O,"Condition 3",'Sheet2'!R:R,A2)

Thanks for the help!
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Hi & welcome to MrExcel.
You need to separate those conditions out like
Excel Formula:
=COUNTIFS(Sheet2!G:G,"Condition 1",Sheet2!I:I,"<>ConditionA",Sheet2!I:I,"<>ConditionB",Sheet2!I:I,"<>ConditionC",Sheet2!I:I,"<>ConditionD")
 
Upvote 0
Solution
Hi & welcome to MrExcel.
You need to separate those conditions out like
Excel Formula:
=COUNTIFS(Sheet2!G:G,"Condition 1",Sheet2!I:I,"<>ConditionA",Sheet2!I:I,"<>ConditionB",Sheet2!I:I,"<>ConditionC",Sheet2!I:I,"<>ConditionD")
Thanks Fluff.

It's solved it, but I'm unsure how? How come you don't need to bracket all the I:I conditions?
 
Upvote 0
You're formula is doing an OR comparison, rather than an AND.
So if I2 was "ConditionA" it isn't equal to ConditionB or ConditionC etc so it will add that row 6 times
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,986
Members
448,538
Latest member
alex78

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