vlookup - null values

Thanks Thanks:  0
Likes Likes:  0
Results 1 to 9 of 9

Thread: vlookup - null values

  1. #1
    New Member
    Join Date
    Jun 2002
    Posts
    16
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

     
    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.

  2. #2
    Legend just_jon's Avatar
    Join Date
    Sep 2002
    Location
    Alabama/State of Disarray
    Posts
    10,473
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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]

  3. #3
    Board Regular
    Join Date
    Sep 2002
    Location
    Leeds
    Posts
    145
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

  4. #4
    Legend just_jon's Avatar
    Join Date
    Sep 2002
    Location
    Alabama/State of Disarray
    Posts
    10,473
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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]

  5. #5
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    81,443
    Post Thanks / Like
    Mentioned
    10 Post(s)
    Tagged
    0 Thread(s)

    Default

    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.

    Assuming too much and qualifying too much are two faces of the same problem.

  6. #6
    MrExcel MVP
    Join Date
    Mar 2002
    Location
    Michigan USA
    Posts
    11,454
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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, D.Eng, P.E.
    Energy Efficient Building Network LLC
    www.energyefficientbuild.com

  7. #7
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    81,443
    Post Thanks / Like
    Mentioned
    10 Post(s)
    Tagged
    0 Thread(s)

    Default

    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.

  8. #8
    MrExcel MVP
    Join Date
    Mar 2002
    Location
    Michigan USA
    Posts
    11,454
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

    ******** LANGUAGE="JavaScript" ************************************************************************>
    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, D.Eng, P.E.
    Energy Efficient Building Network LLC
    www.energyefficientbuild.com

  9. #9
    MrExcel MVP
    Join Date
    Mar 2002
    Location
    Michigan USA
    Posts
    11,454
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

      
    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, D.Eng, P.E.
    Energy Efficient Building Network LLC
    www.energyefficientbuild.com

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  

 

 
DMCA.com