Extract unique distinct values sorted based on sum of adjacent values
Filtering unique distinct text values and sorting them based on the sum of adjacent values can easily be done by creating a pivot table, and I highly recommend it.
But in this blog post I want to show how to do this using an Excel array formula.
Table of Contents
- Extract unique distinct values sorted based on sum of adjacent values - Excel 365
- Extract unique distinct values sorted based on sum of adjacent values - earlier Excel versions
- Filtering unique distinct text values and sorting them based on the sum of adjacent values and criteria - earlier Excel versions
- Filtering unique distinct text values and sorting them based on the sum of adjacent values and criteria - Excel 365
- Get Excel *.xlsx file
1. Extract unique distinct values sorted based on sum of adjacent values - Excel 365
This example demonstrates a formula that lists unique distinct values in column B and returns a sorted list based on the totals in column C from large to small.
Value "CC" is displayed in cells C5 and C7, they are 80 and 30 respectively, and the total is 110.
Value "BB" is displayed in cells C4 and C6, they are 90 and 10 respectively, and the total is 100.
Value "DD" is displayed in cell C9, the value is 100, and the total is 100.
Value "AA" is displayed in cells C3 and C7, they are 60 and 20 respectively, and the total is 80.
Excel 365 dynamic array formula:
Formula in cell F3:
Explaining formula
Step 1 - Extract unique distinct values
The UNIQUE function returns a unique or unique distinct list.
Function syntax: UNIQUE(array,[by_col],[exactly_once])
UNIQUE(B3:B9)
becomes
UNIQUE({"AA";"BB";"CC";"BB";"CC";"AA";"DD"})
and returns
{"AA";"BB";"CC";"DD"}.
Step 2 - Calculate totals based on the unique list
The SUMIF function sums numerical values based on a condition.
Function syntax: SUMIF(range, criteria, [sum_range])
SUMIF(B3:B9,UNIQUE(B3:B9),C3:C9)
becomes
SUMIF({"AA";"BB";"CC";"BB";"CC";"AA";"DD"}, {"AA";"BB";"CC";"DD"}, {60;90;80;10;30;20;100})
and returns
{80;100;110;100}
Step 3 - Sort totals from largest to smallest
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(UNIQUE(B3:B9),SUMIF(B3:B9,UNIQUE(B3:B9),C3:C9),-1)
becomes
SORTBY({"AA";"BB";"CC";"DD"},{60;90;80;10;30;20;100},-1)
and returns
{"CC";"BB";"DD";"AA"}.
Step 4 - Shorten the 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(UNIQUE(B3:B9),SUMIF(B3:B9,UNIQUE(B3:B9),C3:C9),-1)
y - B3:B9
x - UNIQUE(y)
LET(y,B3:B9,x,UNIQUE(y),SORTBY(x,SUMIF(y,x,C3:C9),-1))
2. Extract unique distinct values sorted based on the sum of adjacent values - earlier Excel versions
This formula is for earlier Excel versions.
Array formula in E2:
How to create an array formula
- Copy above array formula
- Double press with left mouse button on cell E3
- Paste array formula
- Press and hold Ctrl + Shift simultaneouslöy
- Press Enter
Formula in cell F3:
Explaining formula in cell E2
Step 1 - Count prior values above the current cell
The COUNTIF function counts values based on a condition or criteria, if the number is 0 (zero) then the corresponding value has not yet been displayed.
NOT(COUNTIF($D$1:D1, $A$2:$A$8))
becomes
NOT(COUNTIF("Unique distinct", {"AA";"BB";"CC";"BB";"CC";"AA";"DD"}))
becomes
NOT({0;0;0;0;0;0;0})
The NOT function returns the boolean opposite to the given argument. The array contains no boolean values, however it does contain their numerical equivavents. TRUE = 1 and FALSE = 0 (zero).
NOT({0;0;0;0;0;0;0})
and returns
{TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}.
Step 2 - IF TRUE then return the corresponding sum
The IF function returns the total if the boolean value is TRUE. FALSE returns "" (nothing).
IF(NOT(COUNTIF($E$2:E2, $B$3:$B$9)),SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),"")
becomes
IF({TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}, SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),"")
The SUMIF function adds numbers and returns a total based on a condition or criteria.
IF({TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}, SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),"")
becomes
IF({TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}, {80;100;110;100;110;80;100},"")
and returns
{80;100;110;100;110;80;100}.
Step 3 - Get the largest number in array
The MAX function returns the largest number in the array ignoring blanks and text values.
MAX(IF(NOT(COUNTIF($E$2:E2, $B$3:$B$9)),SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),""))
becomes
MAX({80;100;110;100;110;80;100})
and returns 110.
 Step 4 - Match number
The MATCH function returns the relative position of a value in a cell range or array.
MATCH(MAX(IF(NOT(COUNTIF($E$2:E2, $B$3:$B$9)),SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),"")), IF(NOT(COUNTIF($E$2:E2, $B$3:$B$9)),SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),""), 0)
becomes
MATCH(110, IF(NOT(COUNTIF($E$2:E2, $B$3:$B$9)),SUMIF($B$3:$B$9, "="&$B$3:$B$9, $C$3:$C$9),""), 0)
becomes
MATCH(110, {80;100;110;100;110;80;100}, 0)
and returns 3.
Step 5 - Get value
The INDEX function returns a value based on row number (and column number if needed)
INDEX($A$2:$A$8, MATCH(MAX(IF(NOT(COUNTIF($D$1:D1, $A$2:$A$8)),SUMIF($A$2:$A$8, "="&$A$2:$A$8, $B$2:$B$8),"")), IF(NOT(COUNTIF($D$1:D1, $A$2:$A$8)),SUMIF($A$2:$A$8, "="&$A$2:$A$8, $B$2:$B$8),""), 0))
becomes
INDEX($A$2:$A$8, 3)
and returns "CC" in cell E2.
Get Excel *.xlsx file
Filter unique distinct list sorted based on sum of adjacent values.xlsx
3. Filtering unique distinct text values and sorting them based on the sum of adjacent values and criteria - earlier Excel versions
This formula is for earlier Excel versions than Excel 365. It extracts values based on the list specified in cells E1 and E2, the formula returns the list sorted based on totals of the adjacent numbers.
Array formula in cell E7:
Formula in cell E7:
Get excel *.xlsx file
filter-unique-distinct-list-sorted-based-on-sum-of-adjacent-values-using-array-formula2.xlsx
4. Filtering unique distinct text values and sorting them based on the sum of adjacent values and criteria - Excel 365
This formula is the same as in section 1 with one difference, values must be in the criteria list in order to be displayed.
Excel 365 dynamic array formula in cell E6:
Formula in cell F6:
Explaining formula
Step 1 - Count values based on criteria
The COUNTIF function calculates the number of cells that is equal to a condition.
Function syntax: COUNTIF(range, criteria)
COUNTIF(F2:F3,B3:B9)
becomes
COUNTIF({"AA";"BB"},{"AA";"BB";"cc";"EE";"cc";"F F";"DD"})
and returns
{1; 1; 0; 0; 0; 0; 0}.
Step 2 - Filter values based on the count
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER(B3:B9,COUNTIF(F2:F3,B3:B9))
becomes
FILTER({"AA";"BB";"cc";"EE";"cc";"F F";"DD"},{1; 1; 0; 0; 0; 0; 0})
and returns
{"AA";"BB"}.
Step 3 - Extract unique distinct values
The UNIQUE function returns a unique or unique distinct list.
Function syntax: UNIQUE(array,[by_col],[exactly_once])
UNIQUE(FILTER(B3:B9,COUNTIF(F2:F3,B3:B9)))
becomes
UNIQUE({"AA";"BB"})
and returns
{"AA";"BB"}.
Step 4 - Calculate totals based on the unique list
The SUMIF function sums numerical values based on a condition.
Function syntax: SUMIF(range, criteria, [sum_range])
SUMIF(B3:B9,UNIQUE(FILTER(B3:B9,COUNTIF(F2:F3,B3:B9))),C3:C9)
becomes
SUMIF({"AA";"BB";"cc";"EE";"cc";"F F";"DD"}, {"AA";"BB"}, {60;90;80;-100;30;-50;0})
and returns
{60;90}.
Step 5 - Sort totals from largest to smallest
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(UNIQUE(FILTER(B3:B9,COUNTIF(F2:F3,B3:B9))),SUMIF(B3:B9,UNIQUE(FILTER(B3:B9,COUNTIF(F2:F3,B3:B9))),C3:C9),-1)
becomes
SORTBY({"AA";"BB"},{60;90},-1)
and returns
{"BB";"AA"}.
Step 6 - Shorten the 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(UNIQUE(FILTER(B3:B9,COUNTIF(F2:F3,B3:B9))),SUMIF(B3:B9,UNIQUE(FILTER(B3:B9,COUNTIF(F2:F3,B3:B9))),C3:C9),-1)
y - B3:B9
x - UNIQUE(FILTER(y,COUNTIF(F2:F3,y)))
LET(y,B3:B9,x,UNIQUE(FILTER(y,COUNTIF(F2:F3,y))),SORTBY(x,SUMIF(y,x,C3:C9),-1))
Unique distinct values category
First, let me explain the difference between unique values and unique distinct values, it is important you know the difference […]
Question: I have two ranges or lists (List1 and List2) from where I would like to extract a unique distinct […]
This article shows how to extract unique distinct values based on a condition applied to an adjacent column using formulas. […]
Excel categories
13 Responses to “Extract unique distinct values sorted based on sum of adjacent values”
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.
[...] Filter unique distinct list sorted based on sum of adjacent values … [...]
How might I go about doing this if the values range from positive to negative. ie.
Text Number
AA 60
BB 90
CC 80
EE -100
CC 30
FF -50
DD 100
Eric,
Array formula in A11:
=INDEX(List_text, MATCH(LARGE(IF(COUNTIF($A$10:A10, List_text)=0, SUMIF(List_text, "="&List_text, List_number), ""), 1), SUMIF(List_text, "="&List_text, List_number)*NOT(COUNTIF($A$10:A10, List_text)), 0)) + CTRL + SHIFT + ENTER. Copy cell A11 and paste it down as far as necessary.
Hi Oscar,
Thanks for the formula above, it fixes the case where there are negative values. But, I'm seeing one error - whenever the sum of numbers for some entry is Zero, then the formula fails. In Eric's example set above, if number corresponding to DD was 0, then your formula stops to work. Can you pls suggest something to fix this? Many thanks in adv, appreciate if you could respond soon. Cheers.
William,
You are right! I have changed this post. I hope it works better now.
Thanks for commenting!
What if i wanted sum value to be sorted in descending order.
Oscar, one more question.
How to modify this formula, to use other unique criteria list array being on another worksheet? For example: unique values match only are - AA and BB from criteria list and A1:A12 range from your example.
Can you help me?
Bill,
read this:
Filtering unique distinct text values and sort them based on sum of adjacent values using a criteria list
Thank you, Oscar!
Hi, Oscar,
So what if to do this single array formula? Is it real? Without prepared criteria list. The criteria list mixed with the others
values. How to extract the same values from other range contained in two ranges and sorted by SUM using single formula?
Please help me, I need to assist someone in the processing of their petty cash so i require the following:
I have certain accounts that represent only an income or expense so what i want to know is if i have columns that Reference; Date; Account; Invoice#; Description; PAID; Cash+- and Balance
Based on the Account number that is used (numeric) I want it to return the value that is in PAID column as ZARfigure into Cash+- as positive or negative based on the account code used: EXAMPLE:
Referance P-003414
Date 18.10.2017
Account 2200 (only expenses run through this account all amounts need to be negative
Invoice # 00001
Description Supplier Payment
Paid 1200
Cash In/out -1200
Balance -1200 - This is a running total
There are 18 accounts that i use in total for this purpose and 14 are Negative and 4 are positive
Thank you
Tamara
As I'm trying to follow this tutorial exactly as shown on the page I find it has major errors, but If I try to adjust based on assumption it still has errors you have some typos or I'm totally missing something.
Jay,
the formulas are quite large. They are not easy to work with.
I have added Excel 365 formulas to this article, I hope you can use those instead.