Using Iserror with If statement and Vlookup

J

juliejg1

I have the following formula in a cell:
=IF($K2="STEEL",VLOOKUP($B2,'Macos 12 Mo. Data'!$A$4:$AU$326,40,FALSE),0)

Problem is that the results of this are used for calculations and K2
sometimes doesn't equal "STEEL" so I get an error. I've tried putting an
Iserror and have the error = 0 but am doing something wrong. Can you help?
 
L

Luke M

An error would occur if the VLOOKUP can not find a result. Perhaps this:
=IF($K2="STEEL",IF(ISERROR(VLOOKUP($B2,'Macos 12 Mo.
Data'!$A$4:$AU$326,40,FALSE)),0,VLOOKUP($B2,'Macos 12 Mo.
Data'!$A$4:$AU$326,40,FALSE)),0)

or

=IF(OR($K2<>"STEEL",ISERROR(VLOOKUP($B2,'Macos 12 Mo.
Data'!$A$4:$AU$326,40,FALSE))),0,VLOOKUP($B2,'Macos 12 Mo.
Data'!$A$4:$AU$326,40,FALSE))
 
M

Mike H

Hi,

The way the formula is set up if 'steel' isn't in B2 it will return zero.
What will give an error is not find the value in B2 in the lookup range and
you can get around that by checking if the lookup value is there before
executing the vlookup

=IF(COUNTIF('Macos 12 Mo.
Data'!$A$4:$A$326,$B2)>0,IF($K2="STEEL",VLOOKUP($B2,'Macos 12 Mo.
Data'!$A$4:$AU$326,40,FALSE),0),"")


--
Mike

When competing hypotheses are otherwise equal, adopt the hypothesis that
introduces the fewest assumptions while still sufficiently answering the
question.
 
J

juliejg1

Thank you Mike....very helpful!


Mike H said:
Hi,

The way the formula is set up if 'steel' isn't in B2 it will return zero.
What will give an error is not find the value in B2 in the lookup range and
you can get around that by checking if the lookup value is there before
executing the vlookup

=IF(COUNTIF('Macos 12 Mo.
Data'!$A$4:$A$326,$B2)>0,IF($K2="STEEL",VLOOKUP($B2,'Macos 12 Mo.
Data'!$A$4:$AU$326,40,FALSE),0),"")


--
Mike

When competing hypotheses are otherwise equal, adopt the hypothesis that
introduces the fewest assumptions while still sufficiently answering the
question.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top