Lookup and return multiple sorted values based on corresponding values in another column
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
- Lookup and return multiple sorted values based on corresponding values in another column - Excel 365
- Lookup and return multiple sorted values based on corresponding values in another column - previous Excel versions
- Lookup and return multiple sorted values based on corresponding values in another column - Excel Table
1. Lookup and return multiple sorted values based on corresponding values in another column - Excel 365
Excel 365 dynamic array formula:
Explaining formula
SORTBY(FILTER(C3:D14, B3:B14=G2),INDEX(FILTER(C3:D14, B3:B14=G2),0,1))
Step 1 - Find values equal to condition
The equal sign lets you compare value to value, the result is a boolean value TRUE or FALSE.
B3:B14=G2
and returns {TRUE; FALSE; ... ; FALSE}
Step 2 - Filter values based on logical expression
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER(C3:D14, B3:B14=G2)
and returns {20,"A"; ... ,"J"}
Step 3 - Extract first column in array
The INDEX function returns a value or reference from a cell range or array, you specify which value based on a row and column number.
Function syntax: INDEX(array, [row_num], [column_num])
INDEX(FILTER(C3:D14, B3:B14=G2),0,1)
and returns {20; 8; 19; 13; 3; 7; 18}.
Step 4 - Sort array based on first column
The SORTBY function sorts a cell range or array based on values in a corresponding range or array.
Function syntax: SORTBY(array, by_array1, [sort_order1], [by_array2, sort_order2],…)
SORTBY(FILTER(C3:D14, B3:B14=G2),INDEX(FILTER(C3:D14, B3:B14=G2),0,1))
and returns {3, "H"; 7, "I"; 8, "C"; 13, "I"; 18, "J"; 19, "D"; 20, "A"}.
Step 5 - Shorten formula
The LET function lets you name intermediate calculation results which can shorten formulas considerably and improve performance.
Function syntax: LET(name1, name_value1, calculation_or_name2, [name_value2, calculation_or_name3...])
SORTBY(FILTER(C3:D14, B3:B14=G2),INDEX(FILTER(C3:D14, B3:B14=G2),0,1))
x - FILTER(C3:D14, B3:B14=G2)
LET(x,FILTER(C3:D14, B3:B14=G2),SORTBY(x,INDEX(x,0,1))
Get the Excel file
Lookup-and-return-multiple-sorted-values-based-on-corresponding-values-in-another-column-Excel-365.xlsx
2. Lookup and return multiple sorted values based on corresponding values in another column- previous Excel versions
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:
Formula in cell F5:
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.
- Copy above formula for cell G5 (Ctrl + c).
- Double press with left mouse button on cell G5.
- Paste array formula (CTRL + v).
- Press and hold CTRL + SHIFT simultaneously.
- Press Enter once.
- 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
- Select cell G5.
- Copy cell (Ctrl + c).
- Select cell range G6:G11.
- Paste (Ctrl + v).
Explaining array formula in cell G5
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", press with left mouse button on the "Evaluate Formula" button.
A dialog box appears, see image above. Press with left mouse button on the "Evaluate" button move to the next calculation step, underlined expression will be evaluated next when you press with left mouse button on the "Evaluate" button.
Text in italic is the most recent evaluated expression. Keep press with left mouse button oning the "Evaluate" button to see all steps, press with left mouse button on "Close" button to dismiss the dialog box.
Step 1 - Filter sort numbers for selected country
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; ""; ""}, 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_value, lookup_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, {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))
and returns H in cell G5.
3. Filter and sort using an 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
- Press with mouse on any value in the data set.
- Press CTRL + T to open the "Create Table" dialog box.
- Press OK button to apply settings and create an Excel Table.
How to filter an Excel Table based on a condition
- Press with left mouse button on the arrow button next to the column header name you want to filter.
- Disable all checkboxes except the condition you want to use. I want to filter the table based on item "Japan".
Note, press with left mouse button on the "(Select All)" checkbox to deselect all checkboxes. This saves you time if you have many checkboxes to deselect.
- Press with left mouse button on "OK" button to apply filter conditions.
How to sort a filtered Excel Table
- Press with mouse on the arrow next to the column header name you want to sort by.
- Press with mouse on "Sort Smallest to Largest" or "Sort Largest to Smallest".
- Press with left mouse button on OK button to apply sorting.
Sort values category
Table of Contents Sort a column - Excel 365 Sort a column using array formula Two columns sorting by the […]
Table of Contents Sort text from two columns combined (array formula) Sort text from multiple cell ranges combined (user defined […]
This article demonstrates a macro and a formula that allows you to sort delimited data in a cell or cell […]
Excel categories
17 Responses to “Lookup and return multiple sorted values based on corresponding values in another column”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
Contact Oscar
You can contact me through this contact form
Hi Oscar,
This is a brilliant solution and it has help me save couple of my hairs (else will be scratching of my head on how this can be done).
Your commitment has really help us grow in out Excel knowledge and I sincerely would like to thank you for doing this.
Best Regards,
Pat
Pat,
thank you!
No array formulas
F5:
=INDEX(MOD(SMALL(($B$3:$B$14=$G$2)*($C$3:$C$14)+($B$3:$B$14<>$G$2)*10^10,ROW(A1)),10^10),0)
G5:
=IFERROR(INDEX($D$3:$D$14,MATCH(F5,INDEX(($B$3:$B$14=$G$2)*($C$3:$C$14)+($B$3:$B$14<>$G$2)*10^10,0),0),0),0)
I hope it useful
Hung,
Your formulas work, thank you for your contribution!
Mr. Oscar
Your works are all wonderful
mahmoud-lee
Thank you!
hi Oscar,
can it be sort for alphabet
momoe,
yes it can.
Array formula in cell F5:
=INDEX($D$3:$D$14, MATCH(SMALL(IF($G$2=$B$3:$B$14, COUNTIF($D$3:$D$14, "<"&$D$3:$D$14), ""), ROW(A1)), IF($G$2=$B$3:$B$14, COUNTIF($D$3:$D$14, "<"&$D$3:$D$14), ""), 0))
Array formula in cell G5:
=SMALL(IF(($G$2=$B$3:$B$14)*(F5=$D$3:$D$14), $C$3:$C$14, ""),COUNTIF($F$5:F5, F5))
Get the Excel *.xlsx file
Lookup-and-return-multiple-values-sorted-in-a-custom-order_q2.xlsx
hi Oscar, thank you.
how about lookup two value and sorted the number from small to large
Hi Oscar,
Thanks for your many great solutions.
I am trying to achieve something similar to this post, but with one major difference. Instead of sorting my results small to large or vice versa, I want only to place those results that meet a specific criteria (from another cell) at the top of the list of results, and all other results can follow in any order.
Can you help?
Simon, why would you want to include results that don't match your criteria?
Hi Oscar,
Thanks for your reply. I hadn't really appreciated that there might be some confusion over this, but I can see now!
I have an array formula, which retrieves records based on two criteria - Project Name & Status. Here is a version of the formula:
{=IF(COUNTIFS(DrugList[Project Name],$B$19,DrugList[Status],$A$24)<ROWS($C$25:C25),"",INDEX(DrugList[BNF Code],SMALL(IF((DrugList[Project Name]=$B$19)+(DrugList[Status]=$A$24)=2,ROW(DrugList[BNF Code])-1),ROW(A1))))}
This can return none, one or many (twenty or more) records, which are displayed in a list format. I want to display all of these records for comparison purposes.
However, some of the records are more important, as they match a third criteria (Strength), which is not currently included in the formula. The value for this third criteria can be referenced from a specific cell ($E$19), and regularly changes dependant upon slicer selections. The results will often contain more than one match with this third criteria, as well as many results that match the two in the array formula, but not the third criteria. I would like to be able to display all of the results which match the first two criteria in the formula (which the formula currently does), AND have the results that match the third criteria appear at the top of that list of results, with all other results displayed below, in any order.
What I can't work out, is how to get those results which match the third criteria as well as the other two, to the top of the list.
I hope that makes sense. Any help would be greatly appreciated.
Simon,
I hope this will be helpful.
Array formula in cell E6:
=INDEX($A$2:$C$9, IF(COUNTIFS($A$2:$A$9, $F$2, $B$2:$B$9, $F$3)>=ROWS($A$1:$A1), SMALL(IF(($A$2:$A$9=$F$2)*($B$2:$B$9=$F$3), MATCH(ROW($A$2:$A$9), ROW($A$2:$A$9)), ""), ROW(A1)), SMALL(IF(($A$2:$A$9=$F$2)*($B$2:$B$9<>$F$3), MATCH(ROW($A$2:$A$9), ROW($A$2:$A$9)), ""), ROW(A1)-COUNTIF($F$5:$F5, $F$3))), COLUMNS($A$1:A1))
What formula is in the F6 for your last replay?
Many thanks,
Dritan,
I am not sure I understand? Replay?
The formula in cell F5:
=SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14, ""),ROW(A1))
changes automatically to
=SMALL(IF($G$2=$B$3:$B$14, $C$3:$C$14, ""),ROW(A2))
in cell F6 when you copy cell F5 and paste to cells below.
Hi Oscar,
Thanks for your many great solutions. I am attempting to return multiple values sorted in a custom order (as you showed us in this post), but with 2 lookup criteria instead of 1. Is this possible?
Awesome formula! I really enjoyed working through it. However, I have run into a snag. I've been using this formula for sales and return information in a retail setting. Something like indexing the item based upon number of pieces or sold or returned from largest to smallest. However, when two different items have the same quantity, the formula looks up and returns the first on the list.
Ex. Formula returns
Item. Qty Item. Qty
bags 1 dress 2
shoes 2 dress 2
dress 2 bags 1
In this example, the second row should say "shoes" not dress. Is there a work around to ensure an item is repeated twice in the result?
Appreciate it!