fbpx
Search
Close this search box.

VLOOKUP the last value

Share

Facebook
Twitter
LinkedIn

VLOOKUP is one of the most useful Excel functions. So much so that I even wrote a book about it. But it has one serious limitation.

It looks up the first occurrence and returns corresponding data.

What if you want to find the last value?

Say, for example, you are looking at a task assignment list and want to know what is the last task assigned to employee Emp13?

vlookup-last-value

We want to extract the task “Make amazing workbook”. Of course our good old VLOOKUP stops once it finds Emp13 and returns the answer as “Create intuitive workbook”.

Let’s learn the formulas required to lookup last value.

VLOOKUP last value

Although I said VLOOKUP last value, we can’t use VLOOKUP formula to do this. Not unless we add a helper column to the original data (or come up with a long array formula version of VLOOKUP). So, instead we are going to use other Excel formulas to find the answer.

2 parts of the problem

There are 2 parts of the find last value problem.

  1. Find the position of last occurrence of given employee (for ex. Emp13’s position would be 5
  2. Return corresponding details (task description, due date or completion status)

Let’s attack each part.

1. Finding the last occurrence position

First take a look at the array formula.

=MAX(ROW(tasks[Employee])*(tasks[Employee]=lookup.value)) - ROW(tasks[[#Headers]])

Remember to press Ctrl+Shift+Enter after typing this.

This array formula returns the position of lookup.value in the list.

How does this formula work?

Let’s go inside out.

(tasks[Employee]=lookup.value) portion:

This will return a bunch of TRUE / FALSE values by checking each item of tasks[Employee] list against lookup.value.

For lookup.value=Emp13, we get below array:

{FALSE;FALSE;FALSE;TRUE;TRUE;FALSE;FALSE;FALSE; FALSE;FALSE;FALSE;FALSE;FALSE;FALSE; FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE; FALSE;FALSE;FALSE;FALSE;FALSE;FALSE}

ROW(tasks[Employee])  portion:

This will return a bunch of running numbers starting with row number of first item in the tasks[Employee] list.

For our data, we get this:

{5;6;7;8;9;10;11;12;13;14;15;16;17;18;19;20;21;22;23;24;25;26;27;28;29;30;31;32;33;34}

ROW(tasks[Employee])*(tasks[Employee]=lookup.value) portion:

This just multiplies the row number array with boolean values, returning an array with 0s for all row numbers except where we have lookup.value as Employee. For lookup.value=Emp13, we get this:

{0;0;0;8;9;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0;0}

MAX (ROW(..) * (...)) portion:

This will tell us the maximum row number where lookup.value occurs in tasks[Employee] list.

So we get 9 as answer.

MAX (...) -  ROW(tasks[[#Headers]]) portion:

As our data doesn’t begin on row 1, we need to subtract the header row position from MAX(…) result. To get the header row number, we are using ROW(tasks[#Headers])

In the end we get the result as 5.

Let’s assume this result is in a cell named last.lookup

2. Return corresponding details

Now that we know the position of last lookup value, we can use INDEX formula to get corresponding details.

So to get the task description, we can use =INDEX(tasks[Task], last.lookup)

And to get the due date, we can use =INDEX(tasks[Due by date],last.lookup)

A twist – VLOOKUP latest value

Now, time for a twist. What if you want to find the latest value by looking at another column like Due by date. In other words, we want to find the latest task for Emp13.

That is your homework. Go ahead and figure out the formula. Once you have answer, post it in comments.

Download VLOOKUP last value example workbook

Please click here to download VLOOKUP last value example workbook. Examine the formulas to understand this technique.

PS: You can find one solution for this problem in downloadable workbook.

More creative ways to lookup your data

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Excel School made me great at work.
5/5

– Brenda

Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

letter grades from test scores in Excel

How to convert test scores to letter grades in Excel?

We can use Excel’s LOOKUP function to quickly convert exam or test scores to letter grades like A+ or F. In this article, let me explain the process and necessary formulas. I will also share a technique to calculate letter grades from test scores using percentiles.

28 Responses to “VLOOKUP the last value”

  1. Deepak says:

    We can also use the non array solution with Lookup.

    =LOOKUP(2,1/(tasks[Employee]=lookup.value),ROW(tasks[Employee]))-ROW(tasks[#Headers])

    • Elias says:

      It still array formula. The only difference is that you don't need Crtl+Shift+Enter to confirm it.

      • Deepak says:

        CSE is not required because it creates virtual array & generally we don't indicate the formula as array where same is not required.

        • Elias says:

          Calling a formula non-array because we don’t confirm it with CSE is generally bad practice. I can’t call the below formula non-array when it obviously is

          =MAX(INDEX(ROW(tasks[Employee])*(tasks[Employee]=lookup.value),0)) - ROW(tasks[#Headers])

          Regards

          • Deepak says:

            For self understanding we know that which one is array or not but others who are learning the basics we can't confused them with these tricks. It depends on the situation how it's called.

          • Elias says:

            Thanks Deepak you just made my point. We shouldn’t confuse others learning the basic by calling the formulas base on the situation. Using Lookup, Index, Sumproduct, etc. to avoid the CSE and saying that they are not array formulas would give them the impression that they perform better.

            Regards

  2. VENKAT says:

    "Finding the last occurrence position"

    Why not sort reverse order of date column and use vlookup

  3. R says:

    Curious, does your book focus only on VLOOKUP, or does it discuss INDEX MATCH as well? I prefer not having to use the name manager and having flexibilty of column order.

  4. Loes Brown says:

    I think this is a bit deceiving. If you sort the dates then the answer would change....

  5. Sujith says:

    I can even use indirect & large function to get the task, change C to D for due date and to E for status \m/ 🙂

    {=INDIRECT("c"&LARGE(IF(tasks[Employee]=lookup.value,ROW(tasks[Employee])),1))}

  6. livio says:

    hello, I have difficulties in reply your example (very useful, fantastic) in my spreadsheet. I use the similar table example (3 columns), with my names and numbers . I can not calculate the value of the cell 'Position', due the fact there is a persistent error in the execution of the beginning of the command
    =max(row(task[Employee])..........
    the error is: task[Employee]
    or so it'appears; my example can not recognize the meaning

    (yes, I used contr+shift+enter also !)

    • Jeff Weir says:

      livio: In your file, is your data in an Excel Table called 'task'?

      • Livio says:

        thanks for support Jeff. I only used different names for cells.
        Do you think it's necessary to maintain absolutely also names ?
        For example: I change 'vlookup.value' with the new name 'ultimo.cercato' and the formula runs well.

      • livio says:

        checking properties of 'task', I noted what it is not possible to change the area of data. In the original example it is located in the range B5:E34 (with $). Why is the name protected ?

        • Chandoo says:

          It is the name of task table. You can edit the table name from Design tab (select any cell inside the table). For more on tables, see this page - http://chandoo.org/wp/2009/09/10/data-tables/

          • Livio says:

            it not possible edit Jeff. There is something else in the spreadsheet I can not put in evidence. the example is very interesting, it's run correctly but it is not possible to export in a new page with new columns and data

          • Livio says:

            consider also that when I try to past in a certain position the list of the names of the speadsheet, it occur all names in clear with their own cells ranges, except the name ‘task’.
            It’s very strange; this name has something special

  7. Livio says:

    consider also that when I try to past in a certain position the list of the names of the speadsheet, it occur all names in clear with their own cells ranges, except the name 'task'.
    It's very strange; this name has something special

  8. Mehmet Günal ÖLÇER says:

    To find the last task for the designated employee the following formula is enough.
    =VLOOKUP(lookup.value;tasks;3;TRUE)

    In VLOOKUP formula the final component can be TRUE or FALSE.
    If it is FALSE you receive the first occurance, if it is TRUE you receive the final occurance, only that the list is supposed to be in ascending order.

    For any comments you can write to "mgolcer@ahoo.com".

  9. Gunal Olcer says:

    How can we find N th occurance, instead of first or last, by using VLOOKUP function. One helper column will be fine.

  10. Rajith Prabhakaran says:

    Thanks for posting this blog.

    I read this post today morning and I found this as a simple tricky question. Everyone have their own comfort zone in Excel to apply their own set of favorite formulas and techniques.

    I felt (MAX, IF) combination with an array would be best approach to this solution and I accept there would be some other fascinating techniques far better than (MAX, IF).

    Example: {=MAX(IF(=,))}, taken your example into consideration.

    I really appreciate your time and effort for this post.

    Thank you!

    • Rajith Prabhakaran says:

      The formula that I posted is not readable due to some technical glitch.

      Example: {=MAX(IF(Employee list=Employee Name,Due by date))}

  11. Mehmet Gunal OLCER says:

    I have a few proposals for new EXCEL FUNCTIONS to be generated.

    a. VLOOKUP, HLOOKUP, LOOKUP functions depending on CELL COLOR.
    b. SUMIF, COUNTIF functions depending on CELL COLOR.

Leave a Reply