Exceljet

Quick, clean, and to the point

Maximum value if

Excel formula: Maximum value if
Generic formula 
{=MAX(IF(range=criteria,values))}
Explanation 

To get a maximum value based on criteria, you can use the MAX function together with the IF function in an array formula. In the example shown, the formula in cell G6 is:

{=MAX(IF(names=F6,times))}

Where names is the named range B6:B17, and times is the named range D6:D17.

Notes: this is an array formula and must be entered with Control + Shift + Enter. Later versions of Excel have a MAXIFS function, see note below.

How this formula works

The IF function is evaluated first. The logical test is an expression that tests all names:

IF(names=F6 // logical test

The result is an array of  TRUE / FALSE values like this:

{TRUE;FALSE;FALSE;TRUE;FALSE;FALSE;TRUE;FALSE;FALSE;TRUE;FALSE;FALSE}

TRUE values correspond to rows where the name is "Hannah". For all other names, the value is FALSE. The "value if true" for IF is the named range times, which contains the full set of times. No "value if false" is provided:

IF(names=F6,times)

The final result from IF is an array like this:

{0.000868055555555556;FALSE;FALSE;0.000902777777777778;FALSE;FALSE;0.000914351851851852;FALSE;FALSE;0.000833333333333333;FALSE;FALSE}

Note: Excel times are fractional values, which explains the long decimals. 

The IF function acts like a filter. Only time values associated with TRUE make it through the filter, other values are replaced with FALSE.

The IF function delivers this array directly to the MAX function, which automatically ignores FALSE values and returns the max time in the array. 

With MAXIFS

The MAXIFS function, available in Excel O365 and Excel 2019, is designed to return a maximum value based on one or more criteria without the need for an array formula. With MAXIFS, the formula in G6 is:

=MAXIFS(times,names,F6)
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.