Filter duplicate values in a range using “contain” condition
The array formula in cell B10 extracts duplicate values from cell range B2:D4 if they contain 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 - Identify duplicates
The COUNTIF function counts values based on a condition or criteria, a value is larger than 1 indicates a dupilcate.
COUNTIF($B$2:$D$4,$B$2:$D$4)>1
becomes
COUNTIF({"Apple", "Banana", "Blackberry";"Orange", "Lemon", "Blood orange";"Blueberry", "Banana", "Orange"}, {"Apple", "Banana", "Blackberry";"Orange", "Lemon", "Blood orange";"Blueberry", "Banana", "Orange"})>1
becomes
{1,2,1;2,1,1;1,2,2}>1
and returns
{FALSE,TRUE, FALSE;TRUE, FALSE,FALSE; FALSE,TRUE, TRUE}.
Step 4 - Multiply arrays
All three corresponding 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))*(COUNTIF($B$2:$D$4, $B$2:$D$4)>1)
becomes
{TRUE,TRUE, TRUE;TRUE, FALSE,TRUE; FALSE,TRUE, TRUE}*{TRUE,TRUE,TRUE; TRUE,TRUE,TRUE; TRUE,TRUE,TRUE}* {FALSE,TRUE, FALSE;TRUE, FALSE,FALSE; FALSE,TRUE, TRUE}
and returns
{0,1,0; 1,0,0; 0,1,1}
Step 5 - 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))*(COUNTIF($B$2:$D$4, $B$2:$D$4)>1), (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, "")
becomes
IF({0,1,0; 1,0,0; 0,1,1}, (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, "")
becomes
IF({0,1,0; 1,0,0; 0,1,1}, {2.33333333333333, 2.25, 2.2; 3.33333333333333, 3.25, 3.2; 4.33333333333333, 4.25, 4.2}, "")
and returns
{"",2.25,""; 3.33333333333333,"",""; "",4.25,4.2}
Step 6 - 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))*(COUNTIF($B$2:$D$4, $B$2:$D$4)>1), (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, ""))
becomes
MIN({"",2.25,""; 3.33333333333333,"",""; "",4.25,4.2})
and returns 2.25.
Step 7 - Find corresponding value
IF(MIN(IF((COUNTIF(B9:$B$9, $B$2:$D$4)=0)*ISNUMBER(SEARCH($C$7, $B$2:$D$4))*(COUNTIF($B$2:$D$4, $B$2:$D$4)>1), (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
{"","","Banana";"","","";"","",""}
Step 8 - 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, {"","","Banana";"","","";"","",""})
and returns "Banana" in cell B10.
Download Excel *.xlsx file
Filter duplicate values in a range using “contain” condition.xlsx
Extract a list of duplicates from a column
The array formula in cell C2 extracts duplicate values from column A. Only one duplicate of each value is displayed […]
Extract a list of duplicates from three columns combined
The following regular formula extracts duplicate values from column B (List1), D (List2) and F (List3) combined, the result is […]
Filter values that exists in all three columns
This article explains how to extract values that exist in three different columns, they must occur in each of the […]
Find min and max unique and duplicate numerical values
Question: How do I get the largest and smallest unique and duplicate value? The image below shows you a list […]
Label groups of duplicate records
Michael asks: I need to identify the duplicates based on the Columns D:H and put in Column C a small […]
Filter duplicates within same date, week or month
The image above demonstrates a formula in cell E3 that extracts duplicate items if they are on the same date. […]
Extract duplicate values with exceptions
The formula in cell E2 returns duplicate values from column A but values in column C are excluded from the […]
Extract a list of duplicates from two columns combined
The following regular formula extracts duplicates from column B (List1) and column D (List2) combined, the result is shown in […]
Extract a list of alphabetically sorted duplicates from a column
The following array formula extracts duplicate values sorted from A to Z from cell range B3:B21. Excel array formula in […]
Extract a list of alphabetically sorted duplicates based on a condition
The following image shows you a data set in column B and C. The formula in cell E2 extracts a […]
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.