+ Reply to Thread
Results 1 to 7 of 7

vlookup not working as expected

  1. #1
    Valued Forum Contributor dmcgov's Avatar
    Join Date
    11-11-2015
    Location
    Florida, USA
    MS-Off Ver
    Office 365 Business
    Posts
    1,518

    vlookup not working as expected

    vlookup error.png

    So lets set the stage for this issue.

    i have a number of NA's in this image. I need for them to fill out.

    so my Project Name (D1) field is: "=VLOOKUP(C7,Formulas!J:K,2,FALSE)"

    and my Project/Job (C7) field is: "=IF(LEFT(D10,4)="Proj","",LEFT(D10,4))"

    and my lookup for the Project/Job (D10) field is found on the formulas tab, range L:L

    if i manually type in the Project/Job (C7) like 1051, then D1 shows up as "2016 Handcraft Maintenance"

    for the range D5:D9, typing in the vendor number (C4), will fill out the range, but not if i use the lookup method

    Currently the formula in D5 is "=VLOOKUP($C$4,Formulas!$Q$1:$V$308,2,FALSE)"

    Im uploading the spreadsheet, use PO xx1 tab to test.
    Attached Files Attached Files

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,460

    Re: vlookup not working as expected

    Try this in C4:

    =VALUE(IF(LEFT(B10,4)="Vend","",LEFT(B10,4)))
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Valued Forum Contributor dmcgov's Avatar
    Join Date
    11-11-2015
    Location
    Florida, USA
    MS-Off Ver
    Office 365 Business
    Posts
    1,518

    Re: vlookup not working as expected

    i get a #Value! in C4, see image below:

    vlookup error 2.png

  4. #4
    Forum Guru
    Join Date
    04-13-2005
    Location
    North America
    MS-Off Ver
    2002/XP and 2007
    Posts
    15,814

    Re: vlookup not working as expected

    The LEFT() function in your C7 formula "=IF(LEFT(D10,4)="Proj","",LEFT(D10,4))" returns a text string "1051". When you hand enter 1051, it will be entered as a number, not a text string. Excel sees the text string "1051" and the number 1051 as different. Your pictures do not show your lookup tables, but I would guess that, in your lookup tables, the lookup values are numbers and not text strings. When you search for the text string "1051" in a list of numbers, it is not found.

    My first thought for a solution is to make sure you C7 formula returns a number and not a text string. I might simply nest the LEFT() function inside of a VALUE() function =IF(...,...,VALUE(LEFT(...))). That should force text "1051" to the number 1051, which will be found in your lookup table.
    Quote Originally Posted by shg
    Mathematics is the native language of the natural world. Just trying to become literate.

  5. #5
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,460

    Re: vlookup not working as expected

    That's because your B10 does not contain the correct data. To get rid of the error message, add IFERROR(...,"") round the formula (...).

  6. #6
    Valued Forum Contributor dmcgov's Avatar
    Join Date
    11-11-2015
    Location
    Florida, USA
    MS-Off Ver
    Office 365 Business
    Posts
    1,518

    Re: vlookup not working as expected

    Quote Originally Posted by MrShorty View Post
    The LEFT() function in your C7 formula "=IF(LEFT(D10,4)="Proj","",LEFT(D10,4))" returns a text string "1051". When you hand enter 1051, it will be entered as a number, not a text string. Excel sees the text string "1051" and the number 1051 as different. Your pictures do not show your lookup tables, but I would guess that, in your lookup tables, the lookup values are numbers and not text strings. When you search for the text string "1051" in a list of numbers, it is not found.

    My first thought for a solution is to make sure you C7 formula returns a number and not a text string. I might simply nest the LEFT() function inside of a VALUE() function =IF(...,...,VALUE(LEFT(...))). That should force text "1051" to the number 1051, which will be found in your lookup table.
    ding ding ding. we have a winner!

    Thanks Mr Shorty for that fix. now everything is golden.

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,460

    Re: vlookup not working as expected

    Thanks for the rep - glad to have helped!

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. [SOLVED] Clearcontesnts not working as expected.
    By rpinxt in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 02-19-2015, 07:16 AM
  2. [SOLVED] VLOOKUP not working as expected.
    By mithandir1 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 01-17-2014, 06:44 PM
  3. ISNA not working as expected
    By micco in forum Excel General
    Replies: 2
    Last Post: 06-30-2011, 01:54 PM
  4. IF statement not working as expected?
    By Aland2929 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 07-30-2009, 07:03 AM
  5. vlookup/if formula not working as expected
    By Shocked in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 09-11-2008, 10:06 AM
  6. [SOLVED] For Each Statement not working as expected
    By Jacqui in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 11-02-2005, 06:17 PM

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1