Explanation
In this example, the goal is to retrieve the lowest 3 scores in column D that appear in a given group, entered as a variable in cell F5. If the group is changed, the formulas should calculate new results. The core of the solution is the SMALL function, which can be used to retrieve the "nth" smallest value in a set of data. The challenge is that the SMALL function does not offer any direct way to apply criteria before calculating a result, so we need to create our own logic to apply criteria.
There are two basic ways to approach this problem. In the current version of Excel, you can use the FILTER function to apply conditions to data before it is delivered to SMALL. In older versions of Excel, you can use the IF function in a traditional array formula. Both approaches are explained below.
Excel Table
For convenience, all data is in an Excel Table named data in the range B5:D16. Excel Tables are a convenient way to work with data in Excel because they (1) automatically expand to include new data and (2) offer structured references, which let you refer to data by name instead of by address. If you are new to Excel Tables, this article provides an overview. Also see this short video:
SMALL function
The SMALL function is used to return the nth smallest value in a set of data like this:
=SMALL(range,n)
where n is a number like 1, 2, 3, etc. For example, you can retrieve the first, second, and third smallest values like this:
=SMALL(range,1) // first smallest
=SMALL(range,2) // second smallest
=SMALL(range,3) // third smallest
The challenge in this problem is that SMALL has no built-in way to apply criteria. A good way to apply criteria is with the FILTER function, as described in the next section.
SMALL with FILTER
In the current version of Excel, the FILTER function can be used to apply criteria inside of SMALL. This is the approach used in the worksheet shown, where the formula in G8 is:
=SMALL(FILTER(data[Score],data[Group]=$F$5),F8)
Working from the inside out, the FILTER function is configured to extract scores for the group in F5 like this:
FILTER(data[Score],data[Group]=$F$5)
Inside FILTER, array is given as the Score column, and the include argument is provided as an expression that compares each value in the Group column to the value in F5 ("A"). Note that $F$5 is an absolute reference, because we don't want this reference to change when the formula is copied down column G. Since there are 12 values in C5:C16, the expression returns an array with 12 TRUE and FALSE values like this:
{TRUE;FALSE;TRUE;FALSE;TRUE;FALSE;TRUE;FALSE;TRUE;FALSE;TRUE;FALSE}
The TRUE values indicate rows where the group equals "A". This array is used by FILTER to retrieve matching data. The result from FILTER is an array that contains the 6 values in group "A":
{90;83;74;87;79;72}
These values are provided to the SMALL function as the array argument. The second argument, k, comes from cell F8:
=SMALL({90;83;74;87;79;72},F8)
=SMALL({90;83;74;87;79;72},1)
=72
In cell G8, the result is 72, the lowest score in group A. As the formula is copied down, the value for k changes and SMALL returns the second and third lowest scores in group A.
SMALL with IF
In Legacy Excel, the FILTER function does not exist, so we need a different approach. The classic solution is to use a traditional array formula based on the IF function:
=SMALL(IF(data[Group]=$F$5,data[Score]),F8)
Note: this is an array formula and must be entered with control + shift + enter in Legacy Excel.
In this formula, the IF function serves the same purpose as the FILTER function: it "filters" the values by group. Since we are running a logical test on 12 separate values in the Group column (C5:C16), we get an array that contains 12 results like this:
{90;FALSE;83;FALSE;74;FALSE;87;FALSE;79;FALSE;72;FALSE}
Notice that only values in group A make it into the array. The values in group B become FALSE when they fail the logical test. This array is returned directly to the SMALL function as the array argument. The value for k comes from cell F8:
=SMALL({90;FALSE;83;FALSE;74;FALSE;87;FALSE;79;FALSE;72;FALSE},F8)
=SMALL({90;FALSE;83;FALSE;74;FALSE;87;FALSE;79;FALSE;72;FALSE},1)
=72
SMALL automatically ignores the FALSE values and returns the smallest number in the remaining values, which is 72. As the formula is copied down, the value for k changes and SMALL returns the second and third smallest values in group A.
Multiple criteria
To apply multiple criteria, you can extend the formula with boolean logic. With FILTER, the generic formula looks like this:
=SMALL(FILTER(data,(criteria1)*(criteria2),n)
Where criteria1 and criteria2 are logical expressions to test specific conditions.
In older versions of Excel, you can use the same idea with the IF function like this:
=SMALL(IF((criteria1)*(criteria2),values),n)
For more information on using Boolean logic in array formulas, see the video below.