Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Looking Backward through a Data Table.

Looking Backward through a Data Table

by Allen Wyatt
(last updated July 13, 2019)

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Zooming In On Your Worksheet

If you have trouble seeing the information presented in a worksheet, you can use Excel's zooming capabilities to ease the ...

Discover More

Embedding TrueType Fonts

If you need to make sure that the fonts in your document can be used by another person or on a different system, you'll ...

Discover More

Showing Only Added Text with Track Changes

Do you want to change how Track Changes displays the markup in your document? Here's how you can completely hide deleted ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (menu)

Using VLOOKUP to Access Information to the Left

One of the most useful function in Excel is VLOOKUP. One thing it won't do, however, is allow you to lookup information ...

Discover More

Making VLOOKUP Case Sensitive

The VLOOKUP function, like other lookup functions in Excel, is not case sensitive. In other words, it doesn't matter ...

Discover More

Returning Blanks with VLOOKUP

Normally the VLOOKUP function returns a value, and if it can't return a value it returns a zero. Here's how you can use ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is eight less than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.