VLOOKUP showing #NA

Glisson

Board Regular
Joined
Nov 22, 2003
Messages
61
Is there a way to keep a cell from showing #NA in the cell where I am performing a VLOOKUP? It seems that there should be a way to make it look cleaner.


Glisson
Excel Neophyte
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Try:

=IF(ISNA(VLOOKUP),"",VLOOKUP))

You can also use 0 instead of "".

Hope that helps,

Smitty
 
Upvote 0
Glisson said:
Is there a way to keep a cell from showing #NA in the cell where I am performing a VLOOKUP? It seems that there should be a way to make it look cleaner.


Glisson
Excel Neophyte

A couple of options...

1]

=IF(ISNUMBER(MATCH(A2,$E$2:$E$20,0)),VLOOKUP(A2,$E$2:$G$20,3,0),"")

2]

=IF(ISNA(SETV(VLOOKUP(A2,$E$2:$G$20,3,0))),"",GETV())

3]

B2:

=IF(ISNA(C2),"",C2)

C2:

=VLOOKUP(A2,$E$2:$G$20,3,0)

The 2nd and 3rd formulas work faster than the 1st. The 2nd requires the morefunc.xll add-in.
 
Upvote 0
So that would turn

=VLOOKUP(B3,Emptable,3,FALSE)

into what? I'm sorry I tried a couple of variations and couldn't get it to work.


P.S. When you look at formulas like this do you see it like grafitti as I do or can you actually "read" it like a second ( or third ) language? just curious. :biggrin:

Glisson
 
Upvote 0
Glisson said:
So that would turn

=VLOOKUP(B3,Emptable,3,FALSE)

into what? I'm sorry I tried a couple of variations and couldn't get it to work.


P.S. When you look at formulas like this do you see it like grafitti as I do or can you actually "read" it like a second ( or third ) language? just curious. :biggrin:

Glisson

1]

=IF(ISNUMBER(MATCH(B3,INDEX(Emptable,0,1)0)),VLOOKUP(B3,Emptable,3,0),"")

2]

=IF(ISNA(SETV(VLOOKUP(B3,Emptable,3,0))),"",GETV())

3]

C3:

=IF(ISNA(D3),"",D3)

D3:

=VLOOKUP(B3,Emptable,3,0)

Note that 0 == FALSE.
 
Upvote 0
P.S. When you look at formulas like this do you see it like grafitti as I do or can you actually "read" it like a second ( or third ) language? just curious.
You'll find that this is Aladin's PRIMARY language. :LOL: He is THE Master!

Smitty
 
Upvote 0
It looks like the net ate one of Aladin's commas, in solution #1 --

=IF(ISNUMBER(MATCH(B3,INDEX(Emptable,0,1),0)),VLOOKUP(B3,Emptable,3,0),"")
 
Upvote 0
Thanks. That got the result I wanted! Now I can go back and pick apart the formula to try to understand it better so that I can use it in other formulas.

I'm just starting to learn his Primary language. You guys are so cool to help guys like me. I never really realized HOW much you could do with Excel. A lot of people here are really pushing the "accepted" limits with it. I played Monopoly written in Excel last night! How cool is that!?

P.S. Is there an ENTRY level book recommended for learning VBA and/or some of these more advanced formulas? I like the books that actually have you work through "projects" to teach you so you can see how to apply the ideas in real world aplications.

Thanks again,
Glisson
 
Upvote 0
John Walkenbach has an Excel VBA for Dummies book. (Although, I've never read it, so I can't tell you how it is).

He also has several others:

http://www.j-walk.com/ss/books/index.htm

Excel Power Programming with VBA is excellent.

Bill Jelen, AKA Mr. Excel, also has "Mr. Excel on Excel", which is supposed to be very good as well.

Those books are a start, but don't forget to post anytime you have a question.

As you've seen, what is Greek to many isn't to the MVP's!

Hope that helps,

Smitty
 
Upvote 0

Forum statistics

Threads
1,213,521
Messages
6,114,104
Members
448,548
Latest member
harryls

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