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: Finding the Dates for Minimums and Maximums.

Finding the Dates for Minimums and Maximums

Written by Allen Wyatt (last updated January 1, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


1

Michael has some data in two columns of a worksheet. Column A is a series of dates and column B contains expenditures for each of those dates. He needs a way to determine the date on which the minimum expenditure occurred and a way to find the date on which the maximum expenditure occurred.

At first glance you might be tempted to think you could use VLOOKUP to figure out the desired date. Unfortunately, that won't work because VLOOKUP keys off of whatever data is in the first column of your data table. Since you want to key off of the amount (looking for the minimum and maximum), you would need to switch the position of the columns, so that column A contained the amount and column B contained the dates. If you do that, you could then use the following formulas to find the dates for the minimum and maximum expenditures, respectively:

=VLOOKUP(MIN(A:A),A:B,2,0)
=VLOOKUP(MAX(A:A),A:B,2,0)

If you cannot change the data columns, then you'll need to forego VLOOKUP and use a different approach, instead. The following two formulas will work with the data as originally specified by Michael:

=INDEX(A:A,MATCH(MIN(B:B),B:B,0))
=INDEX(A:A,MATCH(MAX(B:B),B:B,0))

It is important to note that if there are duplicates of the maximum and/or minimum expenditures, these formulas will only find the dates of the first occurrences. If this is not expected to happen often, a formula such as this could be used to alert the user to the existence of duplicates:

=IF(COUNTIF(B:B, MAX(B:B))>1, "Multiple Maximums ",
INDEX(A:A, MATCH(MAX(B:B), B:B, 0)))

To make this formula work for minimums, just replace the two instances of MAX with MIN and change the word "Maximums" to "Minimums."

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9661) 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: Finding the Dates for Minimums and Maximums.

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

Understanding View Options

Understanding the options available on the View tab of the Options dialog box based on the view you are using.

Discover More

Nudging an Equation

You can adjust where an equation is printed by moving it minute amounts in any direction.

Discover More

A Fast Find-Next

Want a quick, easy way to "search again" for the next occurrence of what you need? Use the technique in this tip and ...

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (menu)

Every Second Tuesday

Need a way to enter dates from every second Tuesday (or some other regular interval)? Excel makes it easy, providing ...

Discover More

Converting Between Buddhist and Gregorian Calendar Systems

Converting from one calendar system to another can be a challenge. The key is identifying the differences between the ...

Discover More

Deciphering a Coded Date

It is no secret that Excel allows you to work with dates in your worksheets. Getting your information into a format that ...

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 three less than 4?

2022-01-01 16:47:29

Henry Noble

Why not simply sort the two columns based on the values in the expenditures column?

Multiple highs and lows will be readily apparent.


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.