Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Returning a Weight and a Date.
Written by Allen Wyatt (last updated April 15, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
David asked how he could return a date associated with the maximum value in a particular column. In David's application, he had two columns containing dates and weights associated with those dates. He could figure out how to determine the maximum weight, but not how to pull the date on which that weight occurred.
In this instance, let's assume that the dates are in column A and the weights are in column B, rows 2 through 45. The following is the method of determining the maximum weight in column B:
=MAX(B2:B45)
You are not limited to using the MAX function; you can also use the LARGE function, which returns the largest specified value in a range. If you want the largest value, you use the function in this way:
=LARGE(B1:B45,1)
So far so good. In order to pull the corresponding date from the cell to the left of the date, all you need to do is use one of the lookup functions. The following example uses the INDEX function:
=INDEX(A2:A45,MATCH(MAX(B2:B45),B2:B45,FALSE),1)
The INDEX function pulls the value from row n, column 1 of range A2:A45. The value of n is determined by using MATCH to get the position number of the maximum value of range B2:B45 within that range. For example, if the highest weight is the fourth one on the list (the weight in row 5), the MATCH expression returns 4, therefore the INDEX function returns the date from row 5, column 1 of range A2:A45.
If you wanted, you could simplify the formula even more by just specifying column information within it. In this way, you could have as many entries as desired in columns A and B:
=INDEX(A:A,MATCH(MAX(B:B),B:B,FALSE),1)
You could just as easily use the LARGE function in place of the MAX function in these formulas. If there are two dates that have the same weight associated with them, then only the first matching date is returned. In addition, you will need to format whatever cell contains your formula with a date format.
If your columns are reversed, meaning that the weights are in column A and the dates are in column B, then you would use the VLOOKUP function instead of INDEX, as shown here:
=VLOOKUP(LARGE(A1:A45,1),A1:B45,2,FALSE)
Again, the MAX function could be used in this formula instead of the LARGE function, if desired.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10651) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Returning a Weight and a Date.
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!
Excel provides several worksheet functions that can be used to count cells containing values--"particularly numeric ...
Discover MoreCircular references occur when a formula includes a reference to the cell in which the formula appears. Here's how you ...
Discover MoreNeed to count the number of cells in a range that are not blank? You can use the COUNTA function of a more complex ...
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 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.
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