vlookup - null values

floored

New Member
Joined
Jun 26, 2002
Messages
16
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.
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
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
 
Upvote 0
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")
 
Upvote 0
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...
Book2
ABCDEFG
1ProductPrice
2a
3b2.5
4c0
5d3.99
6
7
8a 
9b2.5
10c0
11
Sheet1


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.
 
Upvote 0
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
 
Upvote 0
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.
 
Upvote 0
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
Book2
ABCDEFGHI
7
8a
9b
10c0
11d0
12e
13
14
15
16
17b 
18
Sheet3 (2)
</SPAN>
 
Upvote 0
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())
 
Upvote 0

Forum statistics

Threads
1,214,515
Messages
6,119,972
Members
448,933
Latest member
Bluedbw

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