Extract unique distinct values from cell range that begins with string
The array formula in cell B10 extracts unique distinct values from cell range B2:D4 that begins with a given condition specified in cell C7.
Array formula in B10:
Copy cell B10 and paste it down as far as needed.
Explaining formula in cell B10
Step 1 - Identify values beginning with search string
The LEFT function returns a given number of characters from the start of a text string.
LEFT($B$2:$D$4, LEN($C$7))=$C$7
becomes
LEFT({"Apple", "Banana", "Blackberry";"Orange", "Lemon", "Blood orange";"Blueberry", "Banana", "Orange"}, LEN($C$7))=$C$7
becomes
LEFT({"Apple", "Banana", "Blackberry";"Orange", "Lemon", "Blood orange";"Blueberry", "Banana", "Orange"}, 2)=$C$7
becomes
{"Ap","Ba","Bl"; "Or","Le","Bl"; "Bl","Ba","Or"}=$C$7
becomes
{"Ap","Ba","Bl"; "Or","Le","Bl"; "Bl","Ba","Or"}="Bl"
and returns
{FALSE,FALSE,TRUE; FALSE,FALSE,TRUE; TRUE,FALSE,FALSE}.
Step 2 - Keep track of previous values
The COUNTIF function counts values based on a condition or criteria, the first argument contains an expanding cell reference, it grows when the cell is copied to cells below. This makes the formula aware of values displayed in cells above.
COUNTIF(B9:$B$9, $B$2:$D$4)=0
becomes
COUNTIF("Text", {"Apple", "Banana", "Blackberry";"Orange", "Lemon", "Blood orange";"Blueberry", "Banana", "Orange"})=0
becomes
{0,0,0;0,0,0;0,0,0}=0
and returns
{TRUE,TRUE,TRUE; TRUE,TRUE,TRUE; TRUE,TRUE,TRUE}.
Step 3 - Multiply arrays
Both values must be true in order to get the value in a later step.
(LEFT($B$2:$D$4, LEN($C$7))=$C$7)*(COUNTIF(B9:$B$9, $B$2:$D$4)=0)
becomes
{FALSE,FALSE,TRUE; FALSE,FALSE,TRUE; TRUE,FALSE,FALSE}* {TRUE,TRUE,TRUE; TRUE,TRUE,TRUE; TRUE,TRUE,TRUE}
and returns
{0,0,1; 0,0,1; 1,0,0}
Step 4 - Replace TRUE with unique number
The IF function returns a unique number if boolean value is TRUE. FALSE returns "" (nothing). The unique number is needed to find the right value in a later step.
IF((LEFT($B$2:$D$4, LEN($C$7))=$C$7)*(COUNTIF(B9:$B$9, $B$2:$D$4)=0), (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, "")
becomes
IF({0,0,1; 0,0,1; 1,0,0}, (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, "")
becomes
IF({0,0,1; 0,0,1; 1,0,0}, {2.33333333333333, 2.25, 2.2; 3.33333333333333, 3.25, 3.2; 4.33333333333333, 4.25, 4.2}, "")
and returns
{"","",2.2;"","",3.2;4.33333333333333,"",""}
Step 5 - Find smallest value in array
The MIN function returns the smallest number in array ignoring blanks and text values.
MIN(IF((LEFT($B$2:$D$4,LEN($C$7))=$C$7)*(COUNTIF(B9:$B$9, $B$2:$D$4)=0), (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, ""))
becomes
MIN({"","",2.2;"","",3.2;4.33333333333333,"",""})
and returns 2.2.
Step 6 - Find corresponding value
IF(MIN(IF((LEFT($B$2:$D$4, LEN($C$7))=$C$7)*(COUNTIF(B9:$B$9, $B$2:$D$4)=0), (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, ""))=(ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, $B$2:$D$4, "")
becomes
IF(2.2={2.33333333333333, 2.25, 2.2; 3.33333333333333, 3.25, 3.2; 4.33333333333333, 4.25, 4.2}, $B$2:$D$4, "")
becomes
IF({FALSE,FALSE,TRUE;FALSE,FALSE,FALSE;FALSE,FALSE,FALSE}, $B$2:$D$4, "")
and returns
{"","","Blackberry";"","","";"","",""}
Step 7 - Concatenate strings in array
The TEXTJOIN function returns values concatenated ignoring blanks in array.
TEXTJOIN("", TRUE, IF(MIN(IF((LEFT($B$2:$D$4, LEN($C$7))=$C$7)*(COUNTIF(B9:$B$9, $B$2:$D$4)=0), (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, ""))=(ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, $B$2:$D$4, ""))
becomes
TEXTJOIN("", TRUE, {"","","Blackberry";"","","";"","",""})
and returns "Blackberry" in cell B10.
Get Excel *.xlsx file
Extract unique distinct values begins with A in a range using array formula in excel.xlsx
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. […]
The array formula in cell D3 extracts unique distinct values sorted A to Z, from column B to column D. […]
Anura asks: Is it possible to extend this by matching items that meet a criteria? I have a list of […]
Question: How do I extract a unique distinct list from three ranges or lists? The ranges are not necessarily adjacent […]
This article demonstrates formulas that extract unique distinct values and ignore blank empty cells. Table of contents Extract a unique […]
Question: I have cell values spanning over several columns and I want to create a unique list from that range. […]
Question: How do I create a unique distinct list where other columns meet two criteria using excel array formula? Answer: […]
This article demonstrates formulas that extract sorted unique distinct values from a cell range containing also blanks. Unique distinct values […]
This article demonstrates two formulas that extract distinct values from a filtered Excel Table, one formula for Excel 365 subscribers […]
Question: How do I create a unique distinct list where adjacent cell values contain a search string? AA102 CA AA103 […]
Filtering unique distinct text values and sorting them based on the sum of adjacent values can easily be done by […]
EEK asks: I am looking for the same formula on this page, but targeting a range of MxN (spanning multiple […]
This article demonstrates a formula that extracts unique distinct records/rows for a given month specified in cell C2, see the […]
Question: How to create unique distinct year and months from a long date listing (column A)? You can find the […]
Question: How do I create a unique distinct list from a column sorted A to Z using array formula? Array […]
This article demonstrates formulas that list unique distinct values if they contain a specified substring. Table of contents Extract unique […]
Table of Contents Filter unique distinct values based on a date range Filter unique distinct values based on a date […]
Question: I want a unique distinct list to be created from a column where an adjacent column has text cell […]
Functions in this article
More than 1300 Excel formulas
Excel formula categories
Excel categories
3 Responses to “Extract unique distinct values from cell range that begins with string”
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.
Oscar,
Your code has aided me tremendously; THANK YOU!! I have the existing criterion based, unique distinct list formula
I am trying to add "begins with" criteria to rngITEMDescr, such that any item that begins with "PLATE" is excluded from the unique distinct list.
Randy
Randy Braddock
Thank you.
I have added content to this post:
https://www.get-digital-help.com/automatically-filter-unique-row-records-from-multiple-columns/#notbegin
I believe it has the answer to your question.
This article is most helpful. Is it possible to put more than one value in cell C7? I am trying to extract values that begin with two different strings. Thank-you.