Exceljet

Quick, clean, and to the point

Max if criteria match

Excel formula: Max if criteria match
Generic formula 
{=MAX(IF(criteria_range=criteria,value_range))}
Explanation 

To find the maximum value in a range with specific criteria, you can use a basic array formula based on the IF function and MAX function. In the example shown, the formula in cell H8 is:

{=MAX(IF(B5:B9391=H7,E5:E9391))}

which returns the maximum temperature on the date in H7.

Note: this is an array formula and must be entered with Control + Shift + Enter

How this formula works

The example shown contains almost 10,000 rows of data. The data represents temperature readings taken every 2 minutes over a period of days. For any given date (provided in cell H7), we want to get the maximum temperature on that date.

Inside the IF function, logical test is entered as B5:B9391=H7. Because we're comparing the value in H7 against a range of cells (an array), the result will be an array of results, where each item in the array is either TRUE or FALSE. The TRUE values represent dates that match H7.

For the value if true, we provide the range E5:E9391, which fetches all the full set of temperatures in Fahrenheit. This returns an array of values the same size as the first array.

The IF function acts as a filter. Because we provide IF with an array for the logical test, IF returns an array of results. Where the date matches H7, the array contains a temperature value. In all other cases, the array contains FALSE.  In other words, only temperatures associated with the date in H7 survive the trip through the IF function.

The array result from the IF function is delivered directly to the MAX function, which returns the maximum value in the array.

With MAXIFS

In Excel O365 and Excel 2019, the new MAXIFS function can find the maximum value with one or more criteria without the need for an array formula. With MAXIFS, the equivalent formula for the this example is:

=MAXIFS(E5:E9391,B5:B9391,H7)
Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.