Written by Allen Wyatt (last updated August 27, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
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.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Functions are at the heart of Excel's power in working with data. One of the most misunderstood functions provided by ...
Discover MoreIf you have two columns containing dates and weights from those dates, you may want to pick a date associated with a ...
Discover MoreIt is not unusual to use worksheets to collect information over time. As you keep adding information to the worksheet, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments