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.
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
You can use Advanced Filter with a formula

Something like

[TABLE="class: grid"]
<tbody>[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]
[TD="bgcolor: #DCE6F1"]
H
[/TD]
[TD="bgcolor: #DCE6F1"]
I
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
NAME​
[/TD]
[TD]
CTRL​
[/TD]
[TD]
CODE​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
NAME​
[/TD]
[TD="bgcolor: #DCE6F1"]
CTRL​
[/TD]
[TD="bgcolor: #DCE6F1"]
CODE​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD]
Joe​
[/TD]
[TD]
X3F0F3​
[/TD]
[TD]
23​
[/TD]
[TD][/TD]
[TD]
TRUE​
[/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
Joe​
[/TD]
[TD="bgcolor: #DCE6F1"]
X3F0F3​
[/TD]
[TD="bgcolor: #DCE6F1"]
23​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
Smith​
[/TD]
[TD]
Y3MGG1​
[/TD]
[TD]
12​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
Allison​
[/TD]
[TD="bgcolor: #DCE6F1"]
A3D0FH​
[/TD]
[TD="bgcolor: #DCE6F1"]
56​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
Synder​
[/TD]
[TD]
D23SD4​
[/TD]
[TD]
32​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
Tom​
[/TD]
[TD="bgcolor: #DCE6F1"]
X3F1F3​
[/TD]
[TD="bgcolor: #DCE6F1"]
89​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
Allison​
[/TD]
[TD]
A3D0FH​
[/TD]
[TD]
56​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
Rebecca​
[/TD]
[TD="bgcolor: #DCE6F1"]
C3D0FH​
[/TD]
[TD="bgcolor: #DCE6F1"]
73​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
6
[/TD]
[TD]
Tom​
[/TD]
[TD]
X3F1F3​
[/TD]
[TD]
89​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
Helen​
[/TD]
[TD="bgcolor: #DCE6F1"]
S3D2FH​
[/TD]
[TD="bgcolor: #DCE6F1"]
21​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
7
[/TD]
[TD]
Tommy​
[/TD]
[TD]
E23SD4​
[/TD]
[TD]
50​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="bgcolor: #DCE6F1"]
Jennifer​
[/TD]
[TD="bgcolor: #DCE6F1"]
Z3F9F3​
[/TD]
[TD="bgcolor: #DCE6F1"]
91​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
8
[/TD]
[TD]
Richard​
[/TD]
[TD]
H61MN0​
[/TD]
[TD]
11​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
9
[/TD]
[TD]
Ellen​
[/TD]
[TD]
Y3MGG1​
[/TD]
[TD]
22​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
10
[/TD]
[TD]
Samuel​
[/TD]
[TD]
X3MGG1​
[/TD]
[TD]
90​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
11
[/TD]
[TD]
John​
[/TD]
[TD]
L23SD4​
[/TD]
[TD]
89​
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/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]
[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]
[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]
[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]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]


Leave E1 blank
Formula in E2
=ISNUMBER(MATCH(MID(B2,2,2),{"3F";"3H";"22";"3D"},0))

Data > Advanced filter
Pick Copy to
List Range: $A$1:$C$14
Criteria range: $E$1:$E$2
Copy to: $G$1:$I$1

Hope this helps

M.
 
Last edited:
Upvote 0
Similar to M's method:
Code:
Sub MatchC23()
  Dim r As Range, a, ur As Range, c As Range, w As Long, tf As Boolean
  Set r = [A1].CurrentRegion
  a = r.Value
  For Each r In r.Rows
    Set c = Cells(r.Row, 2)
    'ISNUMBER(MATCH(MID(B2,2,2),{"3F";"3H";"22";"3D"},0))
    tf = IsNumeric(Application.Match(Mid(c, 2, 2), Split("3F 3H 22 3D"), 0))
    If tf Then
      If ur Is Nothing Then
        Set ur = r
        Else: Set ur = Union(ur, r)
      End If
    End If
  Next r
  If ur Is Nothing Then Exit Sub
  ur.Copy [D2]
  Application.CutCopyMode = False
End Sub
 
Upvote 0
Here is another macro that you can consider...
Code:
[table="width: 500"]
[tr]
	[td]Sub ExtractListWithConditions()
  Dim TheList As Variant
  TheList = Evaluate("IF(ISNUMBER(MATCH(MID(B2:B14,2,2),{""3F"",""3H"",""22"",""3D""},0)),A2:C14,"""")")
  Application.ScreenUpdating = False
  With Range("E1").Resize(UBound(TheList), 3)
    .Value = TheList
    .SpecialCells(xlBlanks).Delete xlShiftUp
  End With
  Application.ScreenUpdating = True
End Sub[/td]
[/tr]
[/table]
 
Upvote 0
Here is another macro that you can consider...
Code:
[TABLE="width: 500"]
<tbody>[TR]
[TD]Sub ExtractListWithConditions()
  Dim TheList As Variant
  TheList = Evaluate("IF(ISNUMBER(MATCH(MID(B2:B14,2,2),{""3F"",""3H"",""22"",""3D""},0)),A2:C14,"""")")
  Application.ScreenUpdating = False
  With Range("E1").Resize(UBound(TheList), 3)
    .Value = TheList
    .SpecialCells(xlBlanks).Delete xlShiftUp
  End With
  Application.ScreenUpdating = True
End Sub[/TD]
[/TR]
</tbody>[/TABLE]

Sir, would there be a non-macro solution to this? If I could get a list extracted from the CTRL column via posssibly an index/match formula (I have tried multiple ways, but could only get the first matching value copied all the way down, but not a unique list), I guess I will be able to take care of the rest.

Any and all help will be appreciated.
 
Upvote 0
Marcelo, is it possible to extract a list off of CTRL column without using advance filter (i.e., a dynamic formula instead)?
 
Upvote 0
Marcelo, is it possible to extract a list off of CTRL column without using advance filter (i.e., a dynamic formula instead)?

You need an array formula to extract such list

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][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
NAME​
[/td][td]
CTRL​
[/td][td]
CODE​
[/td][td][/td][td]
CTRL List​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Joe​
[/td][td]
X3F0F3​
[/td][td]
23​
[/td][td][/td][td="bgcolor:#D9D9D9"]
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][/tr]

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

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

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

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

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

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

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

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

[tr][td="bgcolor: #DCE6F1"]
12
[/td][td]
Rebecca​
[/td][td]
C3D0FH​
[/td][td]
73​
[/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][/tr]

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


Array formula in E2 copied down
=IFERROR(INDEX(B:B,SMALL(IF(ISNUMBER(MATCH(MID(B$2:B$14,2,2),{"3F";"3H";"22";"3D"},0)),ROW(B$2:B$14)),ROWS(E$2:E2))),"")
Ctrl+Shift+Enter

M.
 
Upvote 0
You need an array formula to extract such list

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][/tr]
[tr][td="bgcolor: #DCE6F1"]
1
[/td][td]
NAME​
[/td][td]
CTRL​
[/td][td]
CODE​
[/td][td][/td][td]
CTRL List​
[/td][/tr]

[tr][td="bgcolor: #DCE6F1"]
2
[/td][td]
Joe​
[/td][td]
X3F0F3​
[/td][td]
23​
[/td][td][/td][td="bgcolor:#D9D9D9"]
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][/tr]

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

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

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

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

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

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

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

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

[tr][td="bgcolor: #DCE6F1"]
12
[/td][td]
Rebecca​
[/td][td]
C3D0FH​
[/td][td]
73​
[/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][/tr]

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


Array formula in E2 copied down
=IFERROR(INDEX(B:B,SMALL(IF(ISNUMBER(MATCH(MID(B$2:B$14,2,2),{"3F";"3H";"22";"3D"},0)),ROW(B$2:B$14)),ROWS(E$2:E2))),"")
Ctrl+Shift+Enter
Just noting that the OP wanted to output three columns of data per row, not just one.
 
Upvote 0
Marcelo, is it possible to extract a list off of CTRL column without using advance filter (i.e., a dynamic formula instead)?

Just noting that the OP wanted to output three columns of data per row, not just one.

Rick,

I understood that in his last post he asked to extract only the CTRL column.

By the way, after extracting CTRL column, regular INDEX/MATCH formulas can easily extract the other columns.

M.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,209
Members
453,022
Latest member
RobertV1609

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