Multi-test IF statement in Calc

I'm trying to build an IF statement that tests if a condition exists in two columns, and assigns the number 1 if it does, and 0 if not. The columns being checked are vLookups which return #NA if an ID is not found in another table. I'm trying to search for cases where an ID# IS returned in two columns meaning the record shows up in both tables.

I can't figure out the syntax for this. I've tried
IF(AND(A1<>"#NA"; B1<>"#NA"),1,0)
on both the vlookup formula columns and on columns that are pasted without formulas. No luck yet. Can someone chime in on this?

Many thanks in advance.

Carl Paulsen wrote:

I'm trying to build an IF statement that tests if a condition exists in
two columns, and assigns the number 1 if it does, and 0 if not. The
columns being checked are vLookups which return #NA if an ID is not
found in another table. I'm trying to search for cases where an ID# IS
returned in two columns meaning the record shows up in both tables.

I can't figure out the syntax for this. I've tried
IF(AND(A1<>"#NA"; B1<>"#NA"),1,0)
on both the vlookup formula columns and on columns that are pasted
without formulas. No luck yet. Can someone chime in on this?

Many thanks in advance.

Try:
   =IF(AND(NOT(ISNA(A1)), NOT(ISNA(B1))),1,0)

Although the cell is displayed as "#N/A", it's not a text value but an error code indicating that a value is not available. ISNA() returns TRUE if a cell contains the #N/A error code, and FALSE otherwise.

Hope that helps.

Mark.

Indeed. But it's simpler than that, in fact. If you apply De Morgan's laws to the expression
AND(NOT(X);NOT(Y))
it simplifies to
NOT(OR(X;Y))
so we can simplify your formula to
=IF(NOT(OR(ISNA(A1);ISNA(B1))),1,0)

But we can do more. The result of the NOT() function - which you are then testing using the IF() function - is a logical value, TRUE or FALSE. But such logical values can be (mis)interpreted as numbers, with TRUE being one and FALSE zero - exactly the values you require. So we don't need the IF() function at all. Just use
=NOT(OR(ISNA(A1);ISNA(B1)))
This function will give you a logical result: TRUE or FALSE. But if you format the result cells as Number, you will see the ones and zeroes that you seek. If you wish to calculate further with these values, you don't even have to worry about formatting: just use them in arithmetic as they are.

I trust this helps.

Brian Barker

Hi,

Brian Barker schrieb:

Carl Paulsen wrote:

I'm trying to build an IF statement that tests if a condition exists
in two columns, and assigns the number 1 if it does, and 0 if not.
The columns being checked are vLookups which return #N/A if an ID is
not found in another table. I'm trying to search for cases where an
ID# IS returned in two columns meaning the record shows up in both
tables.

I can't figure out the syntax for this. I've tried
IF(AND(A1<>"#N/A"; B1<>"#N/A"),1,0)
on both the vlookup formula columns and on columns that are pasted
without formulas. No luck yet. Can someone chime in on this?

Try:
  =IF(AND(NOT(ISNA(A1)), NOT(ISNA(B1))),1,0)

Although the cell is displayed as "#N/A", it's not a text value but an
error code indicating that a value is not available. ISNA() returns
TRUE if a cell contains the #N/A error code, and FALSE otherwise.

Indeed. But it's simpler than that, in fact. If you apply De Morgan's
laws to the expression
AND(NOT(X);NOT(Y))
it simplifies to
NOT(OR(X;Y))
so we can simplify your formula to
=IF(NOT(OR(ISNA(A1);ISNA(B1))),1,0)

And if you exchange the then- and the else-expression, you can drop the NOT function.

=IF(OR(ISNA(A1);ISNA(B1)));0;1)

Kind regards
Regina

And we can also similarly improve my logical expression (that you snipped):
=NOT(OR(ISNA(A1);ISNA(B1)))
into:
=1-OR(ISNA(A1);ISNA(B1))
... where the subtraction of the logical value from one has the effect of negating it.

Apart from its brevity, this has the additional advantage that it becomes a numeric expression so will display as 0 or 1 by default (not as FALSE or TRUE), as the questioner required.

Brian Barker