Author: Oscar Cronquist Article last updated on September 01, 2020

This article demonstrates a formula that extracts values based on a condition and sorts the returned values based on values in another column. This article also explains how to apply a filter and sorting to an Excel Table manually.

What's on this page

Pat asks:

Hi Oscar,
Thanks for creating such a helpful website and I've a question if I would like to return the value with a prefix order would it possible? If not can I just add another column in the data and used it as part of the search criteria?

The array formula in cell G5 looks for the value Japan (cell G2) in column B and returns corresponding values in column D, sorted ascending by the numbers in column C.

Formula in cell G5:

=INDEX($D$3:$D$14, MATCH(SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14, ""), ROWS($A$1:A1)), IF($G$2=$B$3:$B$14, $C$3:$C$14, ""),0))

Formula in cell F5:

=SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14, ""),ROWS($A$1:A1))

You can change the sort order to descending by replacing the SMALL function with the LARGE function.

How to enter an array formula

Excel 365 subscribers do not need to enter the formulas as array formulas.

  1. Copy above formula for cell G5 (Ctrl + c).
  2. Double click cell G5.
  3. Paste array formula (CTRL + v).
  4. Press and hold CTRL + SHIFT simultaneously.
  5. Press Enter once.
  6. Release all keys.

The formula now has curly brackets before and after the array formula {=array_formula},  if you did the above steps correctly.

How to copy array formula to cells below

  1. Select cell G5.
  2. Copy cell (Ctrl + c).
  3. Select cell range G6:G11.
  4. Paste (Ctrl + v).

Explaining array formula in cell G5

Lookup and return multiple values sorted in a custom order evaluate formula

The "Evaluate Formula" tool is great for troubleshooting and examining formulas. Select the cell containing the formula you want to debug. Go to tab "Formulas", click the "Evaluate Formula" button.

Lookup and return multiple values sorted in a custom order evaluate formula1

A dialog box appears, see image above. Click the "Evaluate" button move to the next calculation step, underlined expression will be evaluated next when you click the "Evaluate" button.

Text in italic is the most recent evaluated expression. Keep clicking the "Evaluate" button to see all steps, click "Close" button to dismiss the dialog box.

Step 1 - Filter sort numbers for selected country

Lookup and return multiple values sorted in a custom order IF function

The IF function returns one value if the logical expression returns TRUE and another value if FALSE.

IF(logical_test, valie_if_true, value_if_false)

IF($G$2=$B$3:$B$14,$C$3:$C$14,"")

becomes

{20; ""; 8; 19; ""; 13; ""; 3; 7; 18; ""; ""}

This array is shown in column E in the image above. Only values from column C are shown based on the condition in cell G2 and the corresponding value in column B.

Step 2 - Find k-th smallest value in the array

The SMALL function returns the k-th smallest number from a cell range or an array.

SMALL(array, k)

SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14,""), ROW(A1))

becomes

SMALL({20; ""; 8; 19; ""; 13; ""; 3; 7; 18; ""; ""}, ROW(A1))

becomes

SMALL({20; ""; 8; 19; ""; 13; ""; 3; 7; 18; ""; ""}, 1)

and returns 3.

ROW(A1) changes as we copy the cell to cells below, this makes the array formula dynamic meaning a new value will be returned in each cell.

Step 3 - Find the relative position of the k-th smallest value in array

The MATCH function finds the relative position of a value in a column or array.

MATCH(lookup_valuelookup_array[match_type])

MATCH(SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14, ""),ROW(A1)), IF($G$2=$B$3:$B$14, $C$3:$C$14, ""), 0)

becomes

MATCH(3, IF($G$2=$B$3:$B$14, $C$3:$C$14, ""), 0)

becomes

MATCH(3, {20; ""; 8; 19; ""; 13; ""; 3; 7; 18; ""; ""}, 0)

and returns 8. Number 3 is the eigth value in the array.

Step 4 - Return Item

The INDEX function returns a value based on row and column numbers.

INDEX($D$3:$D$14, MATCH(SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14, ""),ROW(A1)), IF($G$2=$B$3:$B$14, $C$3:$C$14, ""), 0))

becomes

INDEX($D$3:$D$14, 8)

becomes

INDEX({"A"; "B"; "C"; "D"; "E"; "I"; "G"; "H"; "I"; "J"; "K"; "L"}, 8)

and returns H in cell G5.

Filter and sort using an Excel Table

Lookup and return multiple values sorted in a custom order Excel Table

The image above shows an Excel Table with a filter applied to column B (Country) and sorting applied to column C (Sort order).

How to create an Excel Table

Lookup and return multiple sorted values based on corresponding values in another column create table

  1. Click on any value in the data set.
  2. Press CTRL + T to open the "Create Table" dialog box.
  3. Press OK button to apply settings and create an Excel Table.

Lookup and return multiple sorted values based on corresponding values in another column excel table

How to filter an Excel Table based on a condition

Lookup and return multiple sorted values based on corresponding values in another column filter excel table

  1. Click the arrow button next to the column header name you want to filter.
  2. Disable all checkboxes except the condition you want to use. I want to filter the table based on item "Japan".
    Note, click the "(Select All)" checkbox to deselect all checkboxes. This saves you time if you have many checkboxes to deselect.
    Lookup and return multiple sorted values based on corresponding values in another column filter excel table based on a condition
  3. Click "OK" button to apply filter conditions.

Lookup and return multiple sorted values based on corresponding values in another column filtered excel table

How to sort a filtered Excel Table

Lookup and return multiple sorted values based on corresponding values in another column sort filtered excel table

  1. Click on the arrow next to the column header name you want to sort by.
  2. Click on "Sort Smallest to Largest" or "Sort Largest to Smallest".
  3. Click OK button to apply sorting.

Lookup and return multiple values sorted in a custom order Excel Table