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?

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.
- Find the position of last occurrence of given employee (for ex. Emp13’s position would be 5
- 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.

















6 Responses to “Make VBA String Comparisons Case In-sensitive [Quick Tip]”
Another way to test if Target.Value equal a string constant without regard to letter casing is to use the StrCmp function...
If StrComp("yes", Target.Value, vbTextCompare) = 0 Then
' Do something
End If
That's a cool way to compare. i just converted my values to strings and used the above code to compare. worked nicely
Thanks!
In case that option just needs to be used for a single comparison, you could use
If InStr(1, "yes", Target.Value, vbTextCompare) Then
'do something
End If
as well.
Nice tip, thanks! I never even thought to think there might be an easier way.
Regarding Chronology of VB in general, the Option Compare pragma appears at the very beginning of VB, way before classes and objects arrive (with VB6 - around 2000).
Today StrComp() and InStr() function offers a more local way to compare, fully object, thus more consistent with object programming (even if VB is still interpreted).
My only question here is : "what if you want to binary compare locally with re-entering functions or concurrency (with events) ?". This will lead to a real nightmare and probably a big nasty mess to debug.
By the way, congrats for you Millions/month visits 🙂
This is nice article.
I used these examples to help my understanding. Even Instr is similar to Find but it can be case sensitive and also case insensitive.
Hope the examples below help.
Public Sub CaseSensitive2()
If InStr(1, "Look in this string", "look", vbBinaryCompare) = 0 Then
MsgBox "woops, no match"
Else
MsgBox "at least one match"
End If
End Sub
Public Sub CaseSensitive()
If InStr("Look in this string", "look") = 0 Then
MsgBox "woops, no match"
Else
MsgBox "at least one match"
End If
End Sub
Public Sub NotCaseSensitive()
'doing alot of case insensitive searching and whatnot, you can put Option Compare Text
If InStr(1, "Look in this string", "look", vbTextCompare) = 0 Then
MsgBox "woops, no match"
Else
MsgBox "at least one match"
End If
End Sub