If, and, or

Nanaia

Board Regular
Joined
Jan 11, 2018
Messages
224
Office Version
365
Platform
Windows, 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.
 

Some videos you may like

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.

Nanaia

Board Regular
Joined
Jan 11, 2018
Messages
224
Office Version
365
Platform
Windows, MacOS
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.
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
9,912
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.
 

Gerald Higgins

Well-known Member
Joined
Mar 26, 2007
Messages
9,115
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.
 

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,371
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.
 

Watch MrExcel Video

Forum statistics

Threads
1,102,731
Messages
5,488,543
Members
407,645
Latest member
suyoggore

This Week's Hot Topics

  • Timer in VBA - Stop, Start, Pause and Reset
    [CODE=vba][/CODE] Option Explicit Dim CmdStop As Boolean Dim Paused As Boolean Dim Start Dim TimerValue As Date Dim pausedTime As Date Sub...
  • how to updates multiple rows in muliselect listbox
    Hello everyone. I need help with below code. code is only chaning 1st row in mulitiselect list box. i know issue with code...
  • Delete Row from Table
    I am trying to delete a row from a table using VBA using a named range to find what I need to delete. My Range is finding the right cell. In the...
  • Assigning to a variable
    I have a for each block where I want to assign the value in column 5 of the found row to the variable Serv. [CODE=vba] For Each ws In...
  • Way to verify information
    Hi All, I don't know what to call this formula, and therefore can't search. I have a spreadsheet with information I want to reference...
  • Active Cell Address – Inactive Sheet
    How to use VBA to get the cell address of the active cell in an inactive worksheet and then place that cell address in a location on the current...
Top