Exceljet

Quick, clean, and to the point

Conditional median with criteria

Excel formula: Conditional median with criteria
Generic formula 
{=MEDIAN(IF(criteria,range))}
Explanation 

To calculate a conditional median based on one or more criteria you can use an array formula that uses the MEDIAN and IF functions together. In the example shown, the formula in F5 is:

=MEDIAN(IF(group=E5,data))

where "group" is the named range B5:B14, and "data" is the named range C5:C14.

Note: this is an array formula and must be entered with control + shift + enter.

How this formula works

The MEDIAN function has no built-in way to apply criteria. Given a range, it will return the MEDIAN (middle) number in that range. 

To apply criteria, we use the IF function inside MEDIAN to "filter" values. In this example, the IF function filters by group like this:

IF(group=E5,data)

This expression compares each value in the named range "group" against the value in E5 ("A"). Because the criteria is applied to an array with multiple values, the result is an array of TRUE FALSE values like this:

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

In this array each TRUE corresponds to a value in group A. The IF function evaluates these results and returns the corresponding value from the named range "data". The final result from IF is 

{1;2;3;3;5;FALSE;FALSE;FALSE;FALSE;FALSE}

Notice only values in group A have survived, and group B values are now FALSE. This array is returned to the MEDIAN function, which automatically ignores FALSE values and returns median value, 3.

Note: when IF is used this way to filter values with an array operation, the formula must be entered with control + shift + enter.

Additional criteria

To apply more than one criteria, you can nest another IF inside the first IF:

{=MEDIAN(IF(criteria1,IF(criteria2,data)))}

To avoid extra nesting, you can also use boolean logic in the criteria.

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.

Excel foundational video course
Excel Pivot Table video training course
Excel formulas and functions video training course
Excel Shortcuts Video Course
Excel Charts video training course
Video training for Excel Tables