Kirk has a large data table in Excel. Each row has a vehicle number, date (the table is sorted by this column), beginning mileage, and ending mileage. He would like to search backwards through the data table to find the ending mileage for the same vehicle number to use as the beginning mileage in the current row—similar to VLOOKUP but looking bottom to top rather that top to bottom.
There are several ways you can approach this with a formula. Assume, for this example, that the vehicle number is in column A, the date in column B, the starting mileage in column C, and the ending mileage in column D. What you need is a formula you can put in column C that looks up the most recent ending mileage for current vehicle. The following formula provides one approach; you should place it in cell C3:
=LOOKUP(2,1/FIND(A3,A$2:A2,1),D$2:D2)
You can copy the formula down the column as far as you need. If the vehicle number in column A has not appeared earlier in the data table, then the formula will return an error such as #VALUE! or #N/A. In that case, you can easily type over the formula with the starting mileage that you want to use for the vehicle.
Here's another formulaic approach, but this one should be entered as an array formula (by pressing Ctrl+Shift+Enter):
=IF(A3="","",MAX(IF(($A$2:A2=A3)*($D$2:D2),$D$2:D2)))
Again, place the formula in cell C3 and copy it down as far as needed. This one doesn't return an error value if the vehicle hasn't appeared earlier in the data table; it returns a value of 0. You can then type over the formula with the real starting mileage for that vehicle. The following array formula could also be used:
=IF(A3="","",INDIRECT("D"&LARGE(($A$2:A3=A3)*ROW($2:3),2)))
The difference with this array formula is that if the vehicle hasn't appeared earlier in the data table, it returns a #REF! error.
Here are two array formulas that are even shorter that you can use in C3 (and, again, copy down as needed):
=MAX((D$2:D2)*(--(A$2:A2=A3))) =MAX(IF(A$2:A2=A3,D$2:D2))
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11744) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Looking Backward through a Data Table.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
One of the most useful function in Excel is VLOOKUP. One thing it won't do, however, is allow you to lookup information ...
Discover MoreWant to return more than a value when doing a lookup? Here's one way to do it by adding an IF clause to your formula.
Discover MoreWant to be able to take information that is in one cell and match it to data that is contained in a table within a ...
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 © 2021 Sharon Parq Associates, Inc.
Comments