+ Reply to Thread
Results 1 to 13 of 13

VLOOKUP and INDEX/MATCH not functioning (please help)

  1. #1
    Registered User
    Join Date
    08-04-2017
    Location
    UK
    MS-Off Ver
    2013
    Posts
    8

    VLOOKUP and INDEX/MATCH not functioning (please help)

    Purpose: to compare values from column ‘unknown’ to values from column ‘directory’ and to return corresponding value from column ‘name’.
    There is one condition:
    The numbers from the 'unknown' column must be looked up +/-0.001


    My solution is to Truncate them to the 3rd decimal and try three vlookups - real, +0.001, -0.001
    If you have another solution please let me know!



    Tried both VLOOKUP and INDEX/MATCH and both return the same result:
    26 matches for columns for the original number truncated to 3rd decimal (columns D, E, F)
    60 matches for the number truncated to 3rd decimal +0.001 (columns H, I, J)
    5 matches for the number truncated to 3rd decimal -0.001 (columns L, M, N)



    PROBLEM
    No match found in ROW 184. However, you can see visually in row 184 column C (named 'unknown') the value is 444.383, and when I look it up it in column I (which is 444.383+0.001) should return a match as there is a value 444.384 in column A ('named directory').

    Why on row 184 neither VLOOKUP or MATCH/INDEX are NOT working?
    Obviously there might be more matches, which are not shown.


    PLEASE NOTE: same thread exists in the following forums:
    Attached Files Attached Files
    Last edited by westgigo; 12-15-2017 at 03:42 AM.

  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,245

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Many of us are unable or unwilling to access file-sharing sites, so attach the file here, please.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    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
    Registered User
    Join Date
    08-04-2017
    Location
    UK
    MS-Off Ver
    2013
    Posts
    8

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Thank you AliGW.

  4. #4
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    searched data is ascending order, so you do not need to use an exact match
    =VLOOKUP((TRUNC(C2,3)+0.001),$A:$B,2)

  5. #5
    Registered User
    Join Date
    08-04-2017
    Location
    UK
    MS-Off Ver
    2013
    Posts
    8

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Quote Originally Posted by tim201110 View Post
    searched data is ascending order, so you do not need to use an exact match
    =VLOOKUP((TRUNC(C2,3)+0.001),$A:$B,2)
    It is not working like that. This returns matches for absolutely every record, even for values that are not matching at all.

  6. #6
    Forum Guru
    Join Date
    02-27-2016
    Location
    Vietnam
    MS-Off Ver
    2016
    Posts
    5,899

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Try this ...

    =IFERROR(IFERROR(VLOOKUP(TRUNC(C2,3),$A:$B,2,FALSE),
    VLOOKUP(TRUNC(C2-0.001,3),$A:$B,2,FALSE)),
    VLOOKUP(TRUNC(C2+0.001,3),$A:$B,2,FALSE))

  7. #7
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    =iferror(index($b:$b,aggregate(15,6,row($a$2:$a$2654)/(($a$2:$a$2654=$d2)+($a$2:$a$2654=$d2-0.001)+($a$2:$a$2654=$d2+0.001)),1)),"")
    Last edited by tim201110; 12-14-2017 at 09:56 AM. Reason: better

  8. #8
    Registered User
    Join Date
    08-04-2017
    Location
    UK
    MS-Off Ver
    2013
    Posts
    8

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Phuocam and tim201110,

    both formulae work perfect.

    Thank you so much for your prompt response.
    Why it wasn't picking it before?

  9. #9
    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,245

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED. Thanks.

  10. #10
    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,245

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Your post does not comply with Rule 8 of our Forum RULES. Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).

  11. #11
    Registered User
    Join Date
    08-04-2017
    Location
    UK
    MS-Off Ver
    2013
    Posts
    8

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Hi again,

    I still have a question for the same excel file:

    Both formulas work for eliminating errors in the vlookup:
    =IFERROR(IFERROR(VLOOKUP(TRUNC(E2,3),$A:$B,2,FALSE), VLOOKUP(TRUNC(E2-0.001,3),$A:$B,2,FALSE)), VLOOKUP(TRUNC(E2+0.001,3),$A:$B,2,FALSE))
    =IFERROR(INDEX($B:$B,AGGREGATE(15,6,ROW($A$2:$A$2654)/(($A$2:$A$2654=$F2-0.001)+($A$2:$A$2654=$F2+0.001)),1)),"")

    However, since the number from Directory (Column A) varies (exact, + and – 0.001) it is not known the exact digit associated with the result. I need to know the number associated with the matches, if it is exact number, + or – 0.001. How do I do that?
    Last edited by westgigo; 12-15-2017 at 07:32 AM.

  12. #12
    Forum Guru
    Join Date
    02-27-2016
    Location
    Vietnam
    MS-Off Ver
    2016
    Posts
    5,899

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Try:

    =IFERROR(VLOOKUP(TRUNC(C2,3),$A:$B,2,0),
    IFERROR(VLOOKUP(TRUNC(C2-0.001,3),$A:$B,2,0)&"(-0.001)",
    VLOOKUP(TRUNC(C2+0.001,3),$A:$B,2,0)&"(+0.001)"))

  13. #13
    Registered User
    Join Date
    08-04-2017
    Location
    UK
    MS-Off Ver
    2013
    Posts
    8

    Re: VLOOKUP and INDEX/MATCH not functioning (please help)

    Hi Phuocam,

    The formula works fine returning all numbers through vlookup, where exact, + and - are searches are all in one. That is great. However, I will use the unknown number afterwards, so if for example there is a match, the number in the "No" column should be written (for example if there is a match of number 334.273+0.001, it should be just calculated as 334.274 in either column D, H or L).

    Instead of:
    Number | Vlookup/Index
    334.273 | 743219(+0.001)


    In the first column it should be shown the unknown number (either exact, + or -), which is returning the match and the table should look like that:

    Number | Vlookup/Index
    334.274 | 743219

+ 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. VLOOKUP or INDEX/MATCH with multiple column index numbers
    By cerebral87 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 02-22-2017, 07:13 PM
  2. [SOLVED] INDEX+MATCH instead of VLOOKUP+MATCH, why is INDEX a better choice and how to re-write?
    By Renejorgensen in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 11-23-2016, 10:54 AM
  3. Replies: 1
    Last Post: 06-18-2015, 08:45 AM
  4. Replies: 2
    Last Post: 12-18-2014, 09:52 AM
  5. Replies: 3
    Last Post: 05-19-2014, 02:01 PM
  6. Replies: 13
    Last Post: 12-13-2012, 11:44 AM
  7. Replies: 2
    Last Post: 03-16-2012, 12:03 PM

Tags for this Thread

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