Extracting a Unique List Using Complex Criteria

LearnExcl

Board Regular
Joined
Mar 17, 2010
Messages
245
Office Version
  1. 2016
Platform
  1. Windows
Hello, I have the below sample table (the actual table contains 1000 rows):

NAME CTRL CODE
Joe X3F0F3 23
Smith Y3MGG1 12
Synder D23SD4 32
Allison A3D0FH 56
Tom X3F1F3 89
Tommy E23SD4 50
Richard H61MN0 11
Ellen Y3MGG1 22
Samuel X3MGG1 90
John L23SD4 89
Rebecca C3D0FH 73
Helen S3D2FH 21
Jennifer Z3F9F3 91

I would like to extract a unique list from the list above onto another sheet based on the whether the 2nd and 3rd characters of the CTRL numbers match "3F", "3H", "22", "3D". Based on the table above, the result should look like:

[TABLE="width: 500"]
<tbody>[TR]
[TD]Joe[/TD]
[TD]X3F0F3[/TD]
[TD]23[/TD]
[/TR]
[TR]
[TD]Tom[/TD]
[TD]Z3F1F3[/TD]
[TD]89[/TD]
[/TR]
[TR]
[TD]Jennifer[/TD]
[TD]X3F9F3[/TD]
[TD]91[/TD]
[/TR]
[TR]
[TD]Allison[/TD]
[TD]A3D0FH[/TD]
[TD]56[/TD]
[/TR]
[TR]
[TD]Rebecca[/TD]
[TD]C3D0FH[/TD]
[TD]73[/TD]
[/TR]
[TR]
[TD]Helen[/TD]
[TD]S3D2FH[/TD]
[TD]21[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]



There are going to be cases where the list won't have any corresponding data, in case of which the results should be "".

I really appreciate your assistance with it in advance.
 
Awesome! Thank you so much! One thing though, what if I wanted to fetch the results for (2nd character not equal to "4", "7" and "2") AND (2nd and 3rd characters not equal to "5T", "1A" and "6C")? Your assistance will be greatly appreciated.

Thank you in advance.
 
Upvote 0

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
Awesome! Thank you so much! One thing though, what if I wanted to fetch the results for (2nd character not equal to "4", "7" and "2") AND (2nd and 3rd characters not equal to "5T", "1A" and "6C")? Your assistance will be greatly appreciated.

Thank you in advance.

Do you want to do this task in 2 steps? That is:
1. extract CTRL column (post 7)
2. extract, from the extracted values, those that meet these new criteria

M.
 
Last edited:
Upvote 0
I only need to, in one step, extract values from Ctrl column based on the new criteria I specified vs the previous (so, #1 ). I just needed to create new criteria, pulling from the same column. Does that answer your question?
 
Upvote 0
Awesome! Thank you so much! One thing though, what if I wanted to fetch the results for (2nd character not equal to "4", "7" and "2") AND (2nd and 3rd characters not equal to "5T", "1A" and "6C")? Your assistance will be greatly appreciated.

Thank you in advance.

The last criteria seems superfluous since the first criteria is 2nd-3rd characters like 3F,3H,22, 3D
Could you clarify?

M.
 
Upvote 0
This formula is a brand new formula that will be placed under a different column. It is not related to, or part of, the previous formula provided.
 
Upvote 0
Try


[Table="class: grid"][tr][td="bgcolor: #DCE6F1"][/td][td="bgcolor: #DCE6F1"]
A
[/td][td="bgcolor: #DCE6F1"]
B
[/td][td="bgcolor: #DCE6F1"]
C
[/td][td="bgcolor: #DCE6F1"]
D
[/td][td="bgcolor: #DCE6F1"]
E
[/td][td="bgcolor: #DCE6F1"]
F
[/td][td="bgcolor: #DCE6F1"]
G
[/td][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
NAME​
[/td][td]
CTRL​
[/td][td]
CODE​
[/td][td][/td][td]
CTRL List​
[/td][td][/td][td]
New Formula​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Joe​
[/td][td]
X3F0F3​
[/td][td]
23​
[/td][td][/td][td="bgcolor:#D9D9D9"]
X3F0F3​
[/td][td][/td][td="bgcolor:#DCE6F1"]
X3F0F3​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
3
[/td][td]
Smith​
[/td][td]
Y3MGG1​
[/td][td]
12​
[/td][td][/td][td="bgcolor:#D9D9D9"]
A3D0FH​
[/td][td][/td][td="bgcolor:#DCE6F1"]
Y3MGG1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
4
[/td][td]
Synder​
[/td][td]
D23SD4​
[/td][td]
32​
[/td][td][/td][td="bgcolor:#D9D9D9"]
X3F1F3​
[/td][td][/td][td="bgcolor:#DCE6F1"]
A3D0FH​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
5
[/td][td]
Allison​
[/td][td]
A3D0FH​
[/td][td]
56​
[/td][td][/td][td="bgcolor:#D9D9D9"]
C3D0FH​
[/td][td][/td][td="bgcolor:#DCE6F1"]
X3F1F3​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
6
[/td][td]
Tom​
[/td][td]
X3F1F3​
[/td][td]
89​
[/td][td][/td][td="bgcolor:#D9D9D9"]
S3D2FH​
[/td][td][/td][td="bgcolor:#DCE6F1"]
H61MN0​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
7
[/td][td]
Tommy​
[/td][td]
E23SD4​
[/td][td]
50​
[/td][td][/td][td="bgcolor:#D9D9D9"]
Z3F9F3​
[/td][td][/td][td="bgcolor:#DCE6F1"]
Y3MGG1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
8
[/td][td]
Richard​
[/td][td]
H61MN0​
[/td][td]
11​
[/td][td][/td][td][/td][td][/td][td="bgcolor:#DCE6F1"]
X3MGG1​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
9
[/td][td]
Ellen​
[/td][td]
Y3MGG1​
[/td][td]
22​
[/td][td][/td][td][/td][td][/td][td="bgcolor:#DCE6F1"]
C3D0FH​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
10
[/td][td]
Samuel​
[/td][td]
X3MGG1​
[/td][td]
90​
[/td][td][/td][td][/td][td][/td][td="bgcolor:#DCE6F1"]
S3D2FH​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
11
[/td][td]
John​
[/td][td]
L23SD4​
[/td][td]
89​
[/td][td][/td][td][/td][td][/td][td="bgcolor:#DCE6F1"]
Z3F9F3​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
12
[/td][td]
Rebecca​
[/td][td]
C3D0FH​
[/td][td]
73​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
13
[/td][td]
Helen​
[/td][td]
S3D2FH​
[/td][td]
21​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
14
[/td][td]
Jennifer​
[/td][td]
Z3F9F3​
[/td][td]
91​
[/td][td][/td][td][/td][td][/td][td][/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
15
[/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][td][/td][/tr]
[/table]


Array Formula in G2 copied down
=IFERROR(INDEX(B:B,SMALL(IF(ISNA(MATCH(MID(B$2:B$14,2,1),{"4";"7";"2"},0)),IF(ISNA(MATCH(MID(B$2:B$14,2,2),{"5T";"1A";"6C"},0)),ROW(B$2:B$14))),ROWS(G$2:G2))),"")
Ctrl+Shift+Enter

M.
 
Upvote 0
Marcelo, works beautifully. Thank you very much. One last (I mean last) thing I would like to ask is about the construction of a formula for the below conditions under column H and we are attempting to extract a unique list of items (By the way, Column D houses numbers such as 0 or 1 in my actual database):

Where the codes under column C equal to "56" or "21" AND the corresponding values under column D equals 1, extract a unique list of corresponding items from the Ctrl Column. Supposing that D5 and D13 both have 1 in them, the result should only list A3D0FH and S3D2FH. I am truly very much greateful to you for your time and effort in advance.
 
Upvote 0
Try

Array formula in H2 copied down
=IFERROR(INDEX(B:B,SMALL(IF(ISNUMBER(MATCH(C$2:C$14,{56;21},0)),IF(D$2:D$14=1,ROW(B$2:B$14))),ROWS(H$2:H2))),"")
Ctrl+Shift+Enter

M.
 
Upvote 0
Working like a charm! Thank you. Two questions though. First, if I needed to add a 3rd criteria, how would I go about doing that? For instance, if later on I needed to incorporate something like IF(ISNUMBER(MATCH(I$2:I$14,$Z$13,0) into the formula you provided, how would I do that?
Second, would you be able to redo the formula you provided in your last post utilizing the following structure (or somewhere along the lines of it), so that I can better understand the structuration of these formulas?
=IFERROR(INDEX($B$1:$B$1000,MATCH(0,<wbr style="font-family: arial, sans-serif; font-size: 12.8px;">IF(D$1:$D$1000=1,IF($C$1:$C$1000="56",<wbr style="color: rgb(51, 51, 51); background-color: rgb(250, 250, 250); font-family: arial, sans-serif; font-size: 12.8px;">COUNTIF($B$1:B1,$B$1:$B$1000))),0))),"")
 
Upvote 0

Forum statistics

Threads
1,224,830
Messages
6,181,228
Members
453,025
Latest member
Hannah_Pham93

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top