If, and, or

Nanaia

Active Member
Joined
Jan 11, 2018
Messages
306
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Scenario: I am trying to find the best way to search one row across ten non consecutive columns to see if criteria is met. This row is one of a thousand and the columns are ten of ninety-five. My goal is: If B3="V" AND AF3="B" AND Q3-AQ3 <=|2.25| OR AH3="B" AND Q3-AS3 <=|2.25| OR AJ3="B" AND Q3-AU3 <=|2.25| OR AL3="B" AND Q3-AW3 <=|2.25|OR AN3="B" AND Q3-AY3 <=|2.25|OR AP3="B" AND Q3-BA3 <=|2.25|OR AR3="B" AND Q3-BC3 <=|2.25|OR AT3="B" AND Q3-BE3 <=|2.25| OR AV3="B" AND Q3-BG3 <=|2.25| OR AX3="B" AND Q3-BI3 <=|2.25|then TRUE. I know there's a way to nest this but I can't figure out how to get it to work. Everything I've tried has gotten errors so I wanted to ask you guys for suggestions.
Thank you in advance for any assistance.
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Looking at this post is dang confusing so let me try to reword it:
If B3="V" AND
AF3="B" AND Q3-AQ3 <=|2.25|
OR AH3="B" AND Q3-AS3 <=|2.25|
OR AJ3="B" AND Q3-AU3 <=|2.25|
OR AL3="B" AND Q3-AW3 <=|2.25|
OR AN3="B" AND Q3-AY3 <=|2.25|
OR AP3="B" AND Q3-BA3 <=|2.25|
OR AR3="B" AND Q3-BC3 <=|2.25|
OR AT3="B" AND Q3-BE3 <=|2.25|
OR AV3="B" AND Q3-BG3 <=|2.25|
OR AX3="B" AND Q3-BI3 <=|2.25|
then true.
I've tried doing each step then nesting into one formula, but as I mentioned I keep getting errors.
 
Upvote 0
First, I think you mean |Q3-AQ3| <= 2.25, or the difference between Q3 and AQ3 is less than 2.25. If so, you can write your formula like this:

=IF(B3="V",IF(OR(AND(AF3="B",ABS(Q3-AQ3)<=2.25),AND(AH3="B",ABS(Q3-AS3)<=2.25),AND(AJ3="B",ABS(Q3-AU3)<=2.25),AND(AL3="B",ABS(Q3-AW3)<=2.25),AND(AN3="B",ABS(Q3-AY3)<=2.25),AND(AP3="B",ABS(Q3-BA3)<=2.25),AND(AR3="B",ABS(Q3-BC3)<=2.25),AND(AT3="B",ABS(Q3-BE3)<=2.25),AND(AV3="B",ABS(Q3-BG3)<=2.25),AND(AX3="B",ABS(Q3-BI3)<=2.25)),TRUE))

Somewhat large, but straightforward. You can also use this shorter version:

=IF(B3="V",IF(SUMPRODUCT(COUNTIF(OFFSET(AF3,0,{0,2,4,6,8,10,12,14,16,18}),"B"),--(ABS(Q3-SUBTOTAL(9,OFFSET(AQ3,0,{0,2,4,6,8,10,12,14,16,18})))<2.25)),TRUE))

which also works, but is a bit trickier.
 
Upvote 0
Perhaps something like this for a simplified version, which might get you started.

=if(and(B3="V",or(and(AF3="B",(Q3-AQ3)<=2.25),and(AH3="B",(Q3-AQ3)<=2.25)),TRUE,FALSE)

I think this works for two conditions, perhaps you can work out how to extend it to more conditions.

BUT, you have hinted that there may be MANY MORE conditions that you want to test.
If that's the case, there might well be better ways of doing this.
 
Upvote 0
Maybe this array formula...

=AND(B3="V",SUM(IF(MOD(COLUMN(AF3:AX3)-COLUMN(AF3)+1,2)=1,IF(AF3:AX3="B",IF(ABS(Q3-AQ3:BI3)<=2.25,1))))>0)
confirmed with Ctrl+Shift+Enter, not just Enter

M.
 
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,196
Members
452,616
Latest member
intern444

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