Vlookup from the bottom

prabby81

Well-known Member
Joined
Oct 31, 2007
Messages
504
How do I Vlookup starting from the bottom? I just want to pick the last value in a table for a given criteria.

I can do this with VBA, but is there a formula for this?

Thanks!
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
I made a UDF called VlookupNth

It looks up the Nth value in the range. You could use a countif(range,value) in the Nth argument to get the last one...

Formula would be
=Vlookupnth(Value,Range,Colref,Countif(Range,Value))

Code:
Public Function VlookupNth(MyVal As Variant, MyRange As Range, Optional ColRef As Long, _
Optional Nth As Long = 1)
'Similar to Vlookup, but returns the Nth value found from the top of myrange.
'Not necessarily the First.
'The TRUE/FALSE argument usually found in Vlookup is assumed FALSE in this function.  Data does NOT need
'to be sorted, and it searches for EXACT match.
'if ColRef is omitted, uses the number of columns in myrange
'if Nth is omitted, returns the first value found


Dim Count, i As Long
Dim MySheet As Worksheet

Count = 0
Set MySheet = Sheets(MyRange.Parent.Name)
If ColRef = 0 Then ColRef = MyRange.Columns.Count
For i = MyRange.Row To MyRange.Row + MyRange.Rows.Count - 1
    If MySheet.Cells(i, MyRange.Column).Value = MyVal Then
        Count = Count + 1
        If Count = Nth Then
            VlookupNth = MySheet.Cells(i, MyRange.Column + ColRef - 1).Value
            Exit Function
        End If
    End If
Next i
VlookupNth = "Not Found"
End Function
 
Upvote 0
Try...

=LOOKUP(2,1/(LookupVector=LookupValue),ResultVector)

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,224,521
Messages
6,179,290
Members
452,902
Latest member
Knuddeluff

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top