Extract unique distinct values if the value contains the given string
This article demonstrates formulas that list unique distinct values if they contain a specified substring.
Table of contents
1. Extract unique distinct values if the value contains a given string - Excel 365
The following formula lists unique distinct values from cell range B3:B21 if they contain the substring specified in cell D3.
Unique distinct values are all values except duplicates, they are merged into one distinct value.
Excel 365 formula in cell F3:
Explaining formula
Step 1 - Search for a substring in the array
The SEARCH function returns the number of the character at which a specific character or text string is found reading left to right (not case-sensitive)
Function syntax: SEARCH(find_text,within_text, [start_num])
SEARCH(D3, B3:B21)
becomes
SEARCH("r",{"Federer, Roger "; "Djokovic, Novak "; "Murray, Andy "; "Davydenko, Nikolay "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Federer, Roger "; "Davydenko, Nikolay "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Gonzalez, Fernando "; "Blake, James "; "Nalbandian, David "; "Robredo, Tommy "; "Wawrinka, Stanislas "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "})
and returns
{5; #VALUE!; 3; #VALUE!; 1; 8; 5; #VALUE!; 3; 13; 4; 13; #VALUE!; #VALUE!; 1; 4; 10; 11; 6}.
Step 2 - Check if the value is a number
The ISNUMBER function checks if a value is a number, returns TRUE or FALSE.
Function syntax: ISNUMBER(value)
ISNUMBER(SEARCH(S20,R20:R22))
becomes
ISNUMBER({5; #VALUE!; 3; #VALUE!; 1; 8; 5; #VALUE!; 3; 13; 4; 13; #VALUE!; #VALUE!; 1; 4; 10; 11; 6})
and returns
{TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE; FALSE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE}.
Step 3 - Filter values if the value in the array is a number
The FILTER function extracts values/rows based on a condition or criteria.
Function syntax: FILTER(array, include, [if_empty])
FILTER(B3:B21,ISNUMBER(SEARCH(S20,R20:R22)))
becomes
FILTER({"Federer, Roger "; "Djokovic, Novak "; "Murray, Andy "; "Davydenko, Nikolay "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Federer, Roger "; "Davydenko, Nikolay "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Gonzalez, Fernando "; "Blake, James "; "Nalbandian, David "; "Robredo, Tommy "; "Wawrinka, Stanislas "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "},{TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE; FALSE; TRUE; TRUE; TRUE; TRUE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE})
and returns
{"Federer, Roger "; "Murray, Andy "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Federer, Roger "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Gonzalez, Fernando "; "Robredo, Tommy "; "Wawrinka, Stanislas "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "}.
Step 3 - List unique distinct values
The UNIQUE function returns a unique or unique distinct list.
Function syntax: UNIQUE(array,[by_col],[exactly_once])
UNIQUE(FILTER(B3:B21,ISNUMBER(SEARCH(D3,B3:B21))))
becomes
UNIQUE({"Federer, Roger "; "Murray, Andy "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Federer, Roger "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Gonzalez, Fernando "; "Robredo, Tommy "; "Wawrinka, Stanislas "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "})
and returns
{"Federer, Roger "; "Murray, Andy "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Robredo, Tommy "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "}
2. Extract unique distinct values if the value contains a string in earlier Excel versions
The image above demonstrates a formula in cell F3 that extracts unique distinct values from column B if they contain the value in cell D3.
Formula in cell F3:
Explaining formula in cell F3
Step 1 - Prevent duplicates
The COUNTIF function counts cells in cell range based on a condition or criteria. If the value is equal to 0 then it has not been displayed yet.
COUNTIF($F$2:F2, $B$3:$B$21)=0
becomes
COUNTIF("Search results "contain" search value
Unique distinct list", {"Federer, Roger "; "Djokovic, Novak "; "Murray, Andy "; "Davydenko, Nikolay "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Federer, Roger "; "Davydenko, Nikolay "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Gonzalez, Fernando "; "Blake, James "; "Nalbandian, David "; "Robredo, Tommy "; "Wawrinka, Stanislas "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "})=0
becomes
{0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0; 0}=0
and returns
{TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}
Step 2 - Check if values contain string
The SEARCH function returns a number that represents the position of the search string if found. The function returns an error if not found which is alright in this case.
SEARCH($D$3,$B$3:$B$21)
becomes
SEARCH("r",$B$3:$B$21)
and returns
{5; #VALUE!; 3; #VALUE!; 1; 8; 5; #VALUE!; 3; 13; 4; 13; #VALUE!; #VALUE!; 1; 4; 10; 11; 6}.
Step 3 - Multiply arrays
Both values must be TRUE in order to be TRUE meaning if the value has not been displayed yet AND the value contains the string then return TRUE or the equivalent numerical number. TRUE is all numbers except 0 (zero), FALSE is 0 (zero).
{TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE; TRUE}*Â {5; #VALUE!; 3; #VALUE!; 1; 8; 5; #VALUE!; 3; 13; 4; 13; #VALUE!; #VALUE!; 1; 4; 10; 11; 6}
and returns
{5; #VALUE!; 3; #VALUE!; 1; 8; 5; #VALUE!; 3; 13; 4; 13; #VALUE!; #VALUE!; 1; 4; 10; 11; 6}.
Step 4 - Divide 1 with array
The result will return !DIV/0 error if 1 is divided with 0 (0), which the LOOKUP function ignores. It will also ignore #VALUE! errors.
1/((COUNTIF($F$2:F2, $B$3:$B$21)=0)*SEARCH($D$3, $B$3:$B$21))
becomes
1/{5; #VALUE!; 3; #VALUE!; 1; 8; 5; #VALUE!; 3; 13; 4; 13; #VALUE!; #VALUE!; 1; 4; 10; 11; 6}
and returns
{0.2; #VALUE!; 0.333333333333333; #VALUE!; 1; 0.125; 0.2; #VALUE!; 0.333333333333333; 0.0769230769230769; 0.25; 0.0769230769230769; #VALUE!; #VALUE!; 1; 0.25; 0.1; 0.0909090909090909; 0.166666666666667}.
Step 5 - Return value
LOOKUP(2,1/((COUNTIF($F$2:F2,$B$3:$B$21)=0)*SEARCH($D$3,$B$3:$B$21)),$B$3:$B$21)
becomes
LOOKUP(2,{0.2; #VALUE!; 0.333333333333333; #VALUE!; 1; 0.125; 0.2; #VALUE!; 0.333333333333333; 0.0769230769230769; 0.25; 0.0769230769230769; #VALUE!; #VALUE!; 1; 0.25; 0.1; 0.0909090909090909; 0.166666666666667},$B$3:$B$21)
becomes
LOOKUP(2,{0.2; #VALUE!; 0.333333333333333; #VALUE!; 1; 0.125; 0.2; #VALUE!; 0.333333333333333; 0.0769230769230769; 0.25; 0.0769230769230769; #VALUE!; #VALUE!; 1; 0.25; 0.1; 0.0909090909090909; 0.166666666666667}, {"Federer, Roger "; "Djokovic, Novak "; "Murray, Andy "; "Davydenko, Nikolay "; "Roddick, Andy "; "Del Potro, Juan Martin "; "Federer, Roger "; "Davydenko, Nikolay "; "Verdasco, Fernando "; "Gonzalez, Fernando "; "Wawrinka, Stanislas "; "Gonzalez, Fernando "; "Blake, James "; "Nalbandian, David "; "Robredo, Tommy "; "Wawrinka, Stanislas "; "Cilic, Marin "; "Stepanek, Radek "; "Almagro, Nicolas "})
and returns
"Almagro, Nicolas " in cell F3.
Get Excel *.xlsx file
Filter unique distinct values containing string.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
6 Responses to “Extract unique distinct values if the value contains the given 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.
I have a data in same way only difference is that they are in number format i.e. (330-1541) in this way so is there any way i can use the filter for such type of data. Please help me.
Ashok,
did you create an array formula?
[...] For Extracting Records From Data Set (12 Examples) - YouTube Bill Jelen - YouTube Or here... Filter unique distinct values using “contain” condition of a column in excel | Get Digit... I hope this helps. [...]
Do you have examples for using advanced filter for "Not Contains"?
I have a data of this sort...
Probe ID Call ID
USBE1 130226200131-1
USBE1 130226200131-2
USBE1 130226200131-3
USBE1 130226200131-4
USBE1 130226200521-1
USBE1R1 130227143154-1
USBE1R1 130227143154-10
USBE1R1 130227143154-11
USBE1R1 130227143154-12
USBE1R1 130227143154-13
USBE1R1 130227143154-14
USBE1R1 130227143154-15
..The "" condition works on the first column, but not on the second column..I am treating both as text columns. But the advanced filter for "Not" condition on these are not working..any help?
dashil103,
Sorry I don´t understand. What is the desired output?
I would like to do something vaguely similar to this. I would like to filter a list with tho columns. In the first column is an ID ("List 1", "List 2", "List 3", and so on), in the second one is a value. Now i would like to list all the values where the first row contains "List 1". Could you help me with this?