Filter duplicate values from a range that begins with string
The array formula in cell B10 extracts duplicate values from cell range B2:D4 if they begin with the condition specified in cell C7.
Array formula in B10:
copied 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";"Blood orange", "Lemon","Blood orange"; "Blueberry","Banana", "Orange"}, LEN($C$7))=$C$7
becomes
LEFT({"Apple","Banana","Blackberry";"Blood orange", "Lemon","Blood orange"; "Blueberry","Banana", "Orange"}, 1)=$C$7
becomes
{"Ap","Ba","Bl"; "Or","Le","Bl"; "Bl","Ba","Or"}=$C$7
becomes
{"A","B","B";"B","L","B";"B","B","O"}="B"
and returns
{FALSE,TRUE, TRUE;TRUE, FALSE,TRUE; TRUE,TRUE, 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("Duplicates", {"Apple","Banana","Blackberry";"Blood 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, this can be used to find duplicate values.
COUNTIF($B$2:$D$4, $B$2:$D$4)>1
becomes
COUNTIF({"Apple","Banana","Blackberry";"Blood orange", "Lemon","Blood orange"; "Blueberry","Banana", "Orange"}, {"Apple","Banana", "Blackberry";"Blood orange", "Lemon","Blood orange"; "Blueberry","Banana", "Orange"})>1
becomes
{1,2,1;2,1,2;1,2,1}>1
and returns
{FALSE,TRUE, FALSE;TRUE, FALSE,TRUE; FALSE,TRUE, FALSE}.
Step 4 - 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)*(COUNTIF($B$2:$D$4, $B$2:$D$4)>1)
becomes
{FALSE,TRUE, TRUE;TRUE, FALSE,TRUE; TRUE,TRUE, FALSE}* {TRUE,TRUE,TRUE; TRUE,TRUE,TRUE; TRUE,TRUE,TRUE}*Â {FALSE,TRUE, FALSE;TRUE, FALSE,TRUE; FALSE,TRUE, FALSE}
and returns
{0,1,0;1,0,1;0,1,0}
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((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,1,0;1,0,1;0,1,0}, (ROW($B$2:$D$4)+(1/(COLUMN($B$2:$D$4)+1)))*1, "")
becomes
IF({0,1,0;1,0,1;0,1,0}, {2.33333333333333, 2.25, 2.2; 3.33333333333333, 3.25, 3.2; 4.33333333333333, 4.25, 4.2}, "")
and returns
{"",2.25,"";3.33333333333333,"",3.2;"",4.25,""}
Step 6 - 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)*(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,"",3.2;"",4.25,""})
and returns 2.25.
Step 7 - 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)*(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.25={"",2.25,"";3.33333333333333,"",3.2;"",4.25,""}, $B$2:$D$4, "")
becomes
IF({FALSE,TRUE, FALSE;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((LEFT($B$2:$D$4, LEN($C$7))=$C$7)*(COUNTIF(B9:$B$9, $B$2:$D$4)=0)*(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
TEXTJOIN("", TRUE, {"","Banana","";"","","";"","",""})
and returns "Banana" in cell B10.
Get Excel *.xlsx file
Filter duplicate text values in a range using begins with criterion.xlsx
Duplicate values category
The array formula in cell C2 extracts duplicate values from column A. Only one duplicate of each value is displayed […]
This webpage demonstrates formulas that merge three non-adjacent cell ranges. What's on this webpage Extract a list of duplicates from […]
This article explains how to extract values that exist in three different columns, they must occur in each of the […]
Excel categories
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.