Alternative to Vlookup rounding down

Jhmtaylor

New Member
Joined
Oct 1, 2006
Messages
10
I know that Vlookup rounds down if it does not find a perfect match.

I have a problem where if a perfect match is not found the result needs to be the next highest.

Suggestions as to fixes, work arounds or outright tricks et al to solve this problem would be appreciated
 

Some videos you may like

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
I assume your data is sorted as you are using VLOOKUP with the optional 4th argument set to TRUE (or omitted). Thus, you can do what you want with INDEX/MATCH:

Code:
=INDEX(YourDataRange,IF(ISNA(MATCH(YourLookupValue,YourLookupRange,0)),MATCH(YourLookupValue,YourLookupRange,1)+1,MATCH(YourLookupValue,YourLookupRange,0)),YourLookupColumn)

So, if you had data in $A$1:$C$10, and you wanted to lookup value in D1 and data in column C of lookup range, you would use:

Code:
=INDEX($A$1:$C$10,IF(ISNA(MATCH(D1,$A$1:$A$10,0)),MATCH(D1,$A$1:$A$10,1)+1,MATCH(D1,$A$1:$A$10,0)),3)

Hope this makes sense!

Richard
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
I know that Vlookup rounds down if it does not find a perfect match.

I have a problem where if a perfect match is not found the result needs to be the next highest.

Suggestions as to fixes, work arounds or outright tricks et al to solve this problem would be appreciated

For a table, say in A2:B10, sorted on its first column (A2:A10) and X2 housing a lookup value of interest...

=INDEX($B$2:$B$10,MATCH(X2,$A$2:$A$10,1)+(LOOKUP(X2,$A$2:$A$10)<>X2))
 

Watch MrExcel Video

Forum statistics

Threads
1,113,862
Messages
5,544,726
Members
410,630
Latest member
JFORTH97
Top