Alternative to Vlookup rounding down

Jhmtaylor

New Member
Joined
Oct 1, 2006
Messages
12
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
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
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
 
Upvote 0
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))
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,557
Latest member
richa mishra

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