How to Return a Value Left of VLOOKUP’s Lookup Column

If you have ever tried to return a value that physically lies to the left of the lookup column, you quickly realize that this task is difficult to accomplish with the VLOOKUP function.  This is a perfect time to move beyond the VLOOKUP function and explore the INDEX and MATCH functions.

Overview

Consider the following screenshot.

20130829d

We are trying to populate the report’s CustName column.  We would like to look up the CustID from the Customers table, and return the CustName.  The problem is that in the lookup range, the CustName column lies to the left of the CustID column.  That is, the return column lies to the left of the lookup column.  VLOOKUP is a righty, can’t go left.*

And this brings us to the reason we are here, to get the hang of using the INDEX/MATCH combination to return values that lie to the left of the lookup column.  But wait, there’s more.  In addition to being able to return values to the left, this combination doesn’t suffer from another common limitation of the VLOOKUP function.  When the third argument of VLOOKUP is expressed as a static integer value, such as 3, a column inserted between the lookup column and the return column will break the function.  Since the third argument is expressed as an integer, it will not adapt to column inserts when inserted between the lookup and return columns.  The INDEX/MATCH combination does not suffer from this limitation.  Since the arguments are range references, Excel adjusts the formulas to accommodate column inserts.  Alright, enough talk, let’s get to it.

MATCH

Let’s take them one at a time.  The MATCH function returns the relative position of a list item.  If we asked Excel to MATCH “Jun” in a list of month abbreviations, it would return 6.  “Apr” would return 4.  This idea is illustrated in the screenshot below.

20130829a

The syntax of the MATCH function follows:

=MATCH(lookup_value,lookup_array,[match_type])

Where:

  • lookup_value is the value we are trying to find
  • lookup_array is where we are looking
  • [match_type] is typically 0 for exact match, but there are other choices to explore here

In our screenshot, we use the following function to return the relative position of the month name:

=MATCH(C6,B11:B22,0)

We are trying to find the relative position of our month (C6), in the list of month abbreviations (B11:B22), and zero for exact match.

Just remember, the MATCH function returns the relative position of a list item.

INDEX

The INDEX function returns the cell value from a range at a given position.  Technically, it does much more than that, but since we are just getting warmed up, let’s stick with that idea: it returns a cell value from a list at a given position.

The syntax of the INDEX function follows:

=INDEX(array, row_num, [column_num])

Where:

  • array is the range that has the value you want to return
  • row_num is the relative row position that has the value you want to return
  • [column_num] is the optional column number, useful when performing two-dimensional lookups

What we’ll do is use the INDEX function to return a cell value, and we’ll nest the MATCH function in there so that it can tell the INDEX function which row has the value we want.  Our INDEX/MATCH formula will look something like this:

=INDEX(array, MATCH(...))

Where the MATCH function figures out the row number argument.  The MATCH function returns the relative row number to the INDEX function.

Consider the screenshot below:

20130829e

We used the INDEX function to return a value from the CustName column.  For the row_num argument, we used the MATCH function to determine the relative position of the CustID within the CustID column.**

The formula used in C7 is:

=INDEX($B$16:$B$27,MATCH(B7,$C$16:$C$27,0))

Where:

  • $B$16:$B$27 is the list that contains the value we wish to return, the CustName column
  • MATCH(B7,$C$16:$C$27,0) determines the row for the INDEX function
  • Where:
  • B7 is the value we are trying to find, our CustID
  • $C$16:$C$27 is where we are looking, the CustID column
  • 0 means exact match

The INDEX/MATCH combination is quite handy, and can be used to return values that lie to the left of the lookup column.

If you want to play with these functions a bit, feel free to download the IndexMatch Excel file that was used to prepare the screenshots for this post:

IndexMatch

Notes

* There is a very creative way to have the VLOOKUP function go left, which is to use the CHOOSE function as the second argument.  Wow, when I read Richard Schollar’s post on Bill Jelen’s site, I was so impressed! Well done!

** The thing that can be often confusing for long-time VLOOKUPers is the order of the arguments.  VLOOKUP begins with the value we are trying to find. We think about the VLOOKUP function like this: go find this, comma, in here, comma, return this.  When using the INDEX/MATCH combination, the thinking reverses.  We first specify the column that has the value we wish to return.  The thinking becomes this: from this column, return this value.

 

This article was written by Jeff Lenning

43 comments:

  1. Awais Ahmad
    Reply

    Bundle of thanks……..

  2. Punamchand
    Reply

    Thank you very much.
    I was looking for this from many day.

  3. Angela
    Reply

    Wow! Thanks a million. This help me so much and your explanation was simple enough that I understood what I was doing. Thanks again!

  4. Shiva
    Reply

    Wow…. was looking for this from long time. This is great information. Thank you so much. Please share if you have advance excel details

  5. Jonathan
    Reply

    That is a fantastic skill!!!!!! Millions of thanks it saves me so many works on Excel and even VBA!!!

  6. Tuyen Tran
    Reply

    THANK YOU VERY MUCH!!!!!!!!!!!!!!!!!!!!!

  7. didi games
    Reply

    Thanks. I was looking for this excel ‘trick’ for getting help in my data nalsyis.

  8. Lucas
    Reply

    Hi all

    I have been using =IFERROR(INDEX($F$13:$F$1353, MATCH(0,COUNTIF($X$12:X12, $F$13:$F$1353), 0)),””) and it work perfectly in order to bring unique values from a column with repeated values. However I use a filter on the repeated values column “F” and when I deselect any item from the “F” filtered column I would like to have this item removed from the unique items list created. Couldn’t figure out a formula to make this work.

    Thanks in advance!

    1. Kurt LeBlanc
      Reply

      Hey Lucas

      I don’t know of any formula to help you accomplish that…but I do know a Query can be set up to do this and all you do is refresh it:)

      Let me know if you need help setting that up,
      Kurt LeBlanc

  9. Sandeep Bisht
    Reply

    Thanks a lot!!.. Really helpful 🙂

  10. yang
    Reply

    why excel cannot develop vlookup-left function? same as hlookup-up? same format of functions, right?

    1. Kurt LeBlanc
      Reply

      Yang,
      The INDEX() function in Excel can go left as you pointed out. It returns a value given the intersection. I recommend using MATCH() with it to make the formula versatile.

      Thanks,
      Kurt

  11. dinesh
    Reply

    good…
    Nicly explained

  12. Naveen Gupta
    Reply

    Genius…well explained , you saved my time, Thank you very much…

  13. Karl
    Reply

    Wonderfully explained and has saved me so much time. Thank you very much!

  14. Kevin Fay
    Reply

    Well done! One of the clearest and most concise articles on Excel I have seen.

    1. jefflenning Post author
      Reply

      Thanks Kevin!

  15. kiran
    Reply

    thanx, helped me solve my back column vlookup issue.

    1. jefflenning Post author
      Reply

      🙂

  16. Nicole Sigaud
    Reply

    Brilliant !! Thank you so much for saving me lots of frustrating hours trying t solve this “leftie-vlookup” thing!

    1. jefflenning Post author
      Reply

      🙂

  17. Danielle
    Reply

    Thank you for explaining how to think in “notes **”. That made it all clear to me!

  18. MOSES OSOLIKA
    Reply

    Great solution. Simple, concise, effective. Many Thanks to you

  19. Kaleigh
    Reply

    Thank you so much!!!

  20. Steve
    Reply

    For those who like to do this via a custom VBA UDF function (as that’s also easier to explain to non-Excel guru’s):

    Function rev_vlookup(searchString As Variant, searchRange As Range, resultsRange As Range, Optional columnIndexInResultsRange As Integer = 1, Optional exactMatch As Boolean = False)

    rev_vlookup = Application.WorksheetFunction.Index(resultsRange, Application.WorksheetFunction.Match(searchString, searchRange, exactMatch), columnIndexInResultsRange)

    End Function

    1. jefflenning Post author
      Reply

      Very cool…thanks for sharing!!

  21. Al
    Reply

    How can I get it to return a list of matches beyond the first one it finds. I need it to return several matchs

    1. Kurt LeBlanc
      Reply

      Hi Al,

      I believe you are looking for SUMIFS(), AVERAGEIFS(), COUNTIFS()…They give you the result of every row that matches your criteria:) If you need further help, I’m happy to assist in any way I can!

      Kurt LeBlanc

  22. Sadiq
    Reply

    Thanks a lot for this, Jeff. Much appreciated.

  23. Crystal Edwards
    Reply

    I have this working. Now the only thing is, if the text doesn’t have a match it returns #N/A. I would like it to return a 0 when there isn’t a match. How do I do that?

    Thank you.

    1. jefflenning Post author
      Reply

      You could wrap the IFERROR function around it, like this =IFERROR(INDEX(…),0)

      Thanks
      Jeff

  24. Satyajeet
    Reply

    Thanks u sir!

  25. anubha shah
    Reply

    Thank u so much sir….you explained it in a very simple way..

  26. Mahavir
    Reply

    thanks good

  27. vinay
    Reply

    Thanks you So much. It is working great.

    1. Kurt LeBlanc
      Reply

      Very good:)

      Kurt LeBlanc

  28. Soysoi
    Reply

    I need to set up a list of race practice times from fastest to slowest, reading values from a master sheet completed by the runner. There is only one practice time for each day. I have a list of times from fastest to slowest (SMALL fn). I’ve then used VLOOKUP and INDEX/MATCH to find that time (eg. fastest, 2nd fastest) on the master sheet and return the date for that race time. However, where two or more race times are the same, the same date is returned all, even though all 2 or 3 races were run on different days. I get the same outcome with both VLOOKUP and INDEX/MATCH. How can I display the unique date relating to each race time (ie. the date that is in the same row as the race time)? Grateful for any advice you can provide.

    1. Kurt LeBlanc
      Reply

      Hey Soysoi

      I’m not sure if I am reading this correctly, but have you tried just sorting the data by race time and date? You can apply a custom sort and sort by time and ,within each time, by date, so it gives you the earliest date first when you run the same times.

      Let me know if that helps or if I can help you further:)
      Kurt LeBlanc

  29. Scorlion
    Reply

    What If I have repeated values to be lookup for. Example what if Ramsey Electronics and Digital Media, Inc has the same cust ID, it will return only 1 value. How to go about it?

  30. Dinesh Goyal
    Reply

    Very Very Thanks…………….

    1. Jeff Lenning Post author
      Reply

      Welcome 🙂

  31. pallavi
    Reply

    thanks, saves a lot of time!!

Leave a Reply

Your email address will not be published. Required fields are marked *

By submitting this form, you accept the Mollom privacy policy.