Summary

To calculate a conditional mode with one or more criteria you can use an array formula based on the IF and MODE functions. In the example shown, the formula in F5 is:

{=MODE(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.

Generic formula

{=MODE(IF(criteria,data))}

Explanation 

The MODE function has no built-in way to apply criteria. Given a range, it will return the most frequently occurring number in that range.

To apply criteria, we use the IF function inside MODE to filter values in a range. In this example, the IF function filters values by group with an expression like this:

IF(group=E5,data)

This compares each value in the named range "group" against the value in E5, which is "A". Because the logical test is applied to an array with multiple values, the result is an array of TRUE FALSE values:

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

where each TRUE corresponds to a row where the group is "A". This array becomes a filter. For each TRUE, IF returns the corresponding value in the named range "data". FALSE values remain unchanged. The final result of IF is this array:

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

Notice only values in group A have survived, group B values are now FALSE. This array is returned to the MODE function, which automatically ignores FALSE values and returns the most frequently occurring number, which is 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:

{=MODE(IF(criteria1,IF(criteria2,data)))}
Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.