Extract unique distinct text values containing string in a range
The formula in cell B10 extracts unique distinct values from cell range B2:d4 that contains the string specified in cell C7.
Array formula in B10:
To enter an array formula, type the formula in a cell then press and hold CTRL + SHIFT simultaneously, now press Enter once. Release all keys.
The formula bar now shows the formula with a beginning and ending curly bracket telling you that you entered the formula successfully. Don't enter the curly brackets yourself.
Explaining formula in cell B10
Step 1 - Identify values containing search string
The SEARCH function returns a number representing the location of a text string in another string.
ISNUMBER(SEARCH($C$7,$B$2:$D$4))
becomes
ISNUMBER(SEARCH("a",{"Apple", "Banana", "Blackberry"; "Orange", "Lemon", "Blood orange"; "Blueberry", "Banana", "Orange"}))
becomes
ISNUMBER({1,2,3;3,#VALUE!,9;#VALUE!,2,3})
and returns
{TRUE,TRUE, TRUE;TRUE, FALSE,TRUE; FALSE,TRUE, TRUE}
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. 0 (zero) indicates values that not yet have been displayed
COUNTIF(B9:$B$9,$B$2:$D$4)=0
becomes
COUNTIF("Unique distinct values", {"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.
(COUNTIF(B9:$B$9,$B$2:$D$4)=0)*ISNUMBER(SEARCH($C$7,$B$2:$D$4))
becomes
{TRUE,TRUE,TRUE;TRUE,TRUE,TRUE;TRUE,TRUE,TRUE}* {TRUE,TRUE,TRUE;TRUE,FALSE,TRUE;FALSE,TRUE,TRUE}
and returns
{1,1,1;1,0,1;0,1,1}
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((COUNTIF(B9:$B$9,$B$2:$D$4)=0)*ISNUMBER(SEARCH($C$7,$B$2:$D$4)),(ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1,"")
becomes
IF({1,1,1;1,0,1;0,1,1},(ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1,"")
becomes
IF({1,1,1;1,0,1;0,1,1}, {2.33333333333333, 2.25, 2.2; 3.33333333333333, 3.25, 3.2; 4.33333333333333, 4.25, 4.2}, "")
and returns
{2.33333333333333, 2.25,2.2; 3.33333333333333,"", 3.2;"", 4.25, 4.2}
Step 5 - Find smallest value in array
The MIN function returns the smallest number in array ignoring blanks and text values.
MIN(IF((COUNTIF(B9:$B$9,$B$2:$D$4)=0)*ISNUMBER(SEARCH($C$7,$B$2:$D$4)),(ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1,""))
becomes
MIN({2.33333333333333, 2.25,2.2; 3.33333333333333,"", 3.2;"", 4.25, 4.2})
and returns 2.2.
Step 6 - Find corresponding value
IF(MIN(IF((COUNTIF(B9:$B$9,$B$2:$D$4)=0)*ISNUMBER(SEARCH($C$7,$B$2:$D$4)),(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.2;"", 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((COUNTIF(B9:$B$9,$B$2:$D$4)=0)*ISNUMBER(SEARCH($C$7,$B$2:$D$4)),(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
Filter unique distinct text values containing string in a range.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. […]
Excel categories
One Response to “Extract unique distinct text values containing string in a range”
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.
I was working with values in a format like 10 x 20 = 200 , in twenty five values at one time only 5 to 8 values were present others were zero, it helped me a lot ,i extracted required result using = condition now i will have only required result in my sheet.
Thank u very much,God Bless you