Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Looking Backward through a Data Table.

Looking Backward through a Data Table

Written by Allen Wyatt (last updated June 12, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021


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 (11745) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel 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

Creating Registry Keys or Values

The Registry is the central depository of configuration information used by Windows and by programs running on your ...

Discover More

Turning Off Aero

Windows implements a lot of visual effects that can make your screen and desktop look gorgeous. These good looks come at ...

Discover More

Converting Forms to Regular Documents

Word allows you to protect documents that are intended to be used as forms. If you want to convert the form responses ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!

More ExcelTips (ribbon)

Segregating Numbers According to Their Sign

Remember your number line from your early years in school? Some numbers can be below zero (negative numbers) and others ...

Discover More

Using a Numeric Portion of a Cell in a Formula

If you have a mixture of numbers and letters in a cell, you may be looking for a way to access and use the numeric ...

Discover More

Replacing Dashes with Periods

Replacing one character in a text value with another character is easy. All you need to do is use the SUBSTITUTE ...

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}] (all 7 characters, in the sequence shown) 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 0 + 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 ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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.