vlookup - null values :: MrExcel Message Board


 FAQFAQ
   SearchSearch   MemberlistMemberlist   UsergroupsUsergroups   FavoritesFavorites   StatisticsStatistics 
 RegisterRegister 
 ProfileProfile   Log in to check your private messagesLog in to check your private messages   Log inLog in 
Online StoreOnline Store

MrExcel Message Board Forum Index -> Excel Questions

vlookup - null values
Post new topic   Reply to topic
Last Thread | Next Thread  >   Printable version
  Author    Thread

floored
Board Regular


Joined: 27 Jun 2002
Posts: 14


Status: Offline

 Reply with quote  

I am performing a VLOOKUP from one excel worksheet to another. One has 0 as responses and I need to bring those into my other worksheet. I am using a unique ID and keep having the null values come back as 0s as well as the actual O answers. Is there a formula to report my null values as such? Thanks.

Post Thu Feb 13, 2003 2:52 pm 
 View user's profile Send private message

just_jon
MrExcel MVP


Joined: 04 Sep 2002
Posts: 3833
Location: Huntsville AL
Flag: Blank

Status: Offline

 Reply with quote  

Could you please post your vlookup formula?

_________________
just_jon
Book of the Month: I'm Not Really an MVP, I Just Play One on TV [j. jon, 2004]

Post Thu Feb 13, 2003 3:01 pm 
 View user's profile Send private message Send e-mail

vanilladan
Board Master


Joined: 25 Sep 2002
Posts: 145
Location: Leeds

Status: Offline

 Reply with quote  

floored,
Can you distinguish this a little please -
I'm getting confused between Zeros and the letter "O". Are you saying that your column contains
a) zeros,
b) blanks &
c) letter Os,

and that you want Excel to distinguish between them in what it returns?

Vanilladan

Post Thu Feb 13, 2003 3:03 pm 
 View user's profile Send private message Send e-mail

just_jon
MrExcel MVP


Joined: 04 Sep 2002
Posts: 3833
Location: Huntsville AL
Flag: Blank

Status: Offline

 Reply with quote  

No, I believe the OP has valid returns of numeric 0, and has probably structured the VLOOKUP in somewhat the following manner -
=IF(ISNUMBER(VLOOKUP_here),VLOOKUP_Here,0)
In which case, a "no match" will also return a numeric 0; the question {if that is indeed the case} is how to determine a legit 0 return from a found match from a 0 return due to a failed match. The solution would be:
=IF(MATCH(VALUE,ARRAY,0),VLOOKUP_Here,"No Match")

_________________
just_jon
Book of the Month: I'm Not Really an MVP, I Just Play One on TV [j. jon, 2004]

Post Thu Feb 13, 2003 3:25 pm 
 View user's profile Send private message Send e-mail

Aladin Akyurek
.


Joined: 15 Feb 2002
Posts: 13867
Location: The Hague
Flag: Blank

Status: Offline

 Reply with quote  


quote:

On 2003-02-13 09:52, floored wrote:
I am performing a VLOOKUP from one excel worksheet to another. One has 0 as responses and I need to bring those into my other worksheet. I am using a unique ID and keep having the null values come back as 0s as well as the actual O answers. Is there a formula to report my null values as such? Thanks.



Given the nasty problem that you want to solve, that is, distinguishing between retrieved real 0's and empty cells read as 0's, I expect that you would want to download and install the morefunc.xll add-in...

Microsoft Excel - Book2___Running: xl2000 : OS = Windows Windows 2000
(F)ile (E)dit (V)iew (I)nsert (O)ptions (T)ools (D)ata (W)indow (H)elp (A)bout
=

A
B
C
D
E
F
G
1
ProductPrice     
2
a      
3
b2.5     
4
c0     
5
d3.99     
6
       
7
       
8
a 
     
9
b2.5     
10
c0     
11
       
Sheet1 

[HtmlMaker 2.32] To see the formula in the cells just click on the cells hyperlink or click the Name box
PLEASE DO NOT QUOTE THIS TABLE IMAGE ON SAME PAGE! OTHEWISE, ERROR OF JavaScript OCCUR.


The formula used is...

=IF(ISNA(SETV(VLOOKUP(A8,$A$2:$B$5,2,0))),"",IF(INDEX($A$2:$A$5,MATCH(GETV(),$B$2:$B$5,0))=A8,GETV(),""))

In case you can't install morefunc, search this site for V, a UDF by Dunn, which can be substituted for both SETV and GETV.


_________________
For MOREFUNC.XLL, see http://longre.free.fr/english/index.html
For more on morefunc, see Function Descriptions

Post Thu Feb 13, 2003 8:57 pm 
 View user's profile Send private message

Yogi Anand
MrExcel MVP


Joined: 13 Mar 2002
Posts: 5639
Location: Michigan USA

Status: Offline

 Reply with quote  

Hi floored:

One of the ways would be to use the following formulation ...

=IF(VLOOKUP($F17,$A$8:$B$12,2)="","",VLOOKUP($F17,$A$8:$B$12,2))

in this formulation lookup value is in cell F17, and the lookup table is in cells A8:B12


_________________
Regards!
Yogi Anand

Post Thu Feb 13, 2003 10:05 pm 
 View user's profile Send private message

Aladin Akyurek
.


Joined: 15 Feb 2002
Posts: 13867
Location: The Hague
Flag: Blank

Status: Offline

 Reply with quote  


quote:

On 2003-02-13 17:05, Yogi Anand wrote:
Hi floored:

One of the ways would be to use the following formulation ...

=IF(VLOOKUP($F17,$A$8:$B$12,2)="","",VLOOKUP($F17,$A$8:$B$12,2))

in this formulation lookup value is in cell F17, and the lookup table is in cells A8:B12





Hard (expensive) to combine with also controlling for #N/A. If the latter is not needed, it's certainly the way to take.

Post Thu Feb 13, 2003 10:28 pm 
 View user's profile Send private message

Yogi Anand
MrExcel MVP


Joined: 13 Mar 2002
Posts: 5639
Location: Michigan USA

Status: Offline

 Reply with quote  

Hi Aladin:

I had at also looked at the following formulation ...

=IF(MATCH(VLOOKUP($F17,$A$8:$B$12,2),B8:B12,0)<>MATCH($F$17,A8:A12,0),"",VLOOKUP($F17,$A$8:$B$12,2))

but this some severe constraints of its own

Microsoft Excel - Book2___Running: xl97 : OS = Windows 98
(F)ile (E)dit (V)iew (I)nsert (O)ptions (T)ools (D)ata (W)indow (H)elp (A)bout
=

A
B
C
D
E
F
G
H
I
7
         
8
a        
9
b        
10
c0       
11
d0       
12
e        
13
         
14
         
15
         
16
         
17
     b  
 
18
         
Sheet3 (2) 

[HtmlMaker 2.20] To see the formula in the cells just click on the cells hyperlink or click the Name box
PLEASE DO NOT QUOTE THIS TABLE IMAGE ON SAME PAGE! OTHEWISE, ERROR OF JavaScript OCCUR.



_________________
Regards!
Yogi Anand

Post Thu Feb 13, 2003 10:47 pm 
 View user's profile Send private message

Yogi Anand
MrExcel MVP


Joined: 13 Mar 2002
Posts: 5639
Location: Michigan USA

Status: Offline

 Reply with quote  

Although, in the last formulation, I could avoid some recalculation by use of setv and getv ...

=IF(MATCH(SETV(VLOOKUP($F17,$A$8:$B$12,2)),B8:B12,0)<>MATCH($F$17,A8:A12,0),"",GETV())

_________________
Regards!
Yogi Anand

Post Thu Feb 13, 2003 10:50 pm 
 View user's profile Send private message
  Display posts from previous:      

MrExcel Message Board Forum Index -> Excel Questions


Forum Jump:
Jump to:  

Post new topic   Reply to topic
Page 1 of 1



Add To Favorites

 


Forum Rules:
You cannot post new topics in this forum
You cannot reply to topics in this forum
You cannot edit your posts in this forum
You cannot delete your posts in this forum
You cannot vote in polls in this forum

Powered by phpBB: 2.0.4 © 2001 phpBB Group

Need help posting your first question? Read how to post

Need extra help ? Couldn't get the answer you needed ? Get a free quote from our Consulting Team

Download Colo's HTML Maker utility for displaying your Excel Worksheet on the board.

Download VB HTML Maker to post your code on the board


Check out our new index to 485 Excel Articles.


Return to MrExcel Consulting

All contents Copyright 1998-2004 by MrExcel.com
If you believe information posted here is from your copyrighted source, notify us per the Terms of Use
Excel is a registered trademark of the Microsoft Corporation.
MrExcel is a registered trademark of Tickling Keys, Inc.