Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Adjusting the VLOOKUP Function

John has a lookup table of ascending numerical values in column A and corresponding text values in column B. When he uses the VLOOKUP function it returns the text value for the numerical value equal to or less than the specified lookup value. John really wants the first value equal to or greater than the lookup value.

There is no way to change how VLOOKUP does its work; it will always match to the value equal to or less than the lookup value. An option, though, is to modify the formula used to do the actual lookup. Consider the following formula, which assumes that the value you want to use for your lookup is in cell D1:

=IF(VLOOKUP(D1,$A$1:$A$10,1)=D1,VLOOKUP(D1,$A$1:$B$10,2),
INDEX($B$1:$B$10,1+MATCH(D1,$A$1:$A$10)))

If the value in D1 is an exact match to a value in column A, then the regular VLOOKUP formula is used. If it isn't, then VLOOKUP is abandoned in favor of the INDEX function in conjunction with the MATCH function.

If you are able to sort your data table in descending order, you can use a shorter formula:

=INDEX($A$1:$B$10,MATCH(D1,$A$1:$A$10,-1),2)

The MATCH function uses the D1 value to look for the smallest value that is great than or equal to that value. (This is what the -1 parameter specifies.) The MATCH function returns the row number of the proper row, and then this is used by INDEX to actually fetch the value.

Another interesting approach to the problem is to use the inverse of the lookup values as a control column that will be used to actually look up information from the data table. For instance, let's assume that your data table is in A1:B10, with the actual numerical values you use for the lookup in column A. You need to insert a column to the left of your data table. Into the first cell of this new column (now column A), insert the following formula:

=1/B1

This provides the inverse of the value in B1, and you can copy it down the cells in column A. Your data table now has three columns, A1:C10. Next, sort your data table based on this new column, in ascending order.

Now you make a slight modification to your lookup formula so that it looks up the inverse of what you want. Assuming that the value you want to use for your lookup is in cell E1, you would use the following formula:

=VLOOKUP(1/E1,$A$1:$C$10,3)

What you effectively end up with is the desired value, from column C, that is associated with the value in column B that is equal to or less than the value in E1.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3090) applies to Microsoft Excel 97, 2000, 2002, and 2003.

Related Tips:

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

ashish mehra    09 Oct 2014, 08:12
If you want to know more about "Index Formula vs. Vlookup Formula", check this link ........

http://www.exceltip.com/lookup-formulas/index-formula-vs-vlookup-formula.html
Mike Epstein    15 Mar 2014, 19:07
Sometimes reciprocals cause problems. Why not use the negative instead? After inserting a new column A, type into A1 "=-b1" (instead of "1/b1") and fill down the column. Sort A1:C10 on column A ascending. Then use =vlookup(-e1,$a$1:$c$10,3).
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.