Extract records based on two criteria

basic101

New Member
Joined
Mar 10, 2019
Messages
1
Hello! im just newbie in excel my question is what formula do I need to get just subjects of all Basic and Common type.
My sample dataset;
Type
Subject
Basic
Subject 1
Basic
Subject 3
Common
Subject 2
Core
Subject 1
Common
Subject 3
Core
Subject 1

<tbody>
</tbody>












I want extracted records to be:
Basic
Subject 1
Basic
Subject 3
Common
Subject 2
Common
Subject 3

<tbody>
</tbody>

Thank you.
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
with PowerQuery (Get&Transform)

TypeSubjectTypeSubject
BasicSubject 1BasicSubject 1
BasicSubject 3BasicSubject 3
CommonSubject 2CommonSubject 2
CoreSubject 1CommonSubject 3
CommonSubject 3CoreSubject 1
CoreSubject 1

Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"Type"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Subject", each List.Distinct(Table.Column([Count],"Subject"))),
    #"Expanded Subject" = Table.ExpandListColumn(#"Added Custom", "Subject")
in
    #"Expanded Subject"[/SIZE]

in a meantime you can filter Core ;)

Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Grouped Rows" = Table.Group(Source, {"Type"}, {{"Count", each _, type table}}),
    #"Added Custom" = Table.AddColumn(#"Grouped Rows", "Subject", each List.Distinct(Table.Column([Count],"Subject"))),
    #"Expanded Subject" = Table.ExpandListColumn(#"Added Custom", "Subject"),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Subject", each ([Type] <> "Core"))
in
    #"Filtered Rows"[/SIZE]

TypeSubjectTypeSubject
BasicSubject 1BasicSubject 1
BasicSubject 3BasicSubject 3
CommonSubject 2CommonSubject 2
CoreSubject 1CommonSubject 3
CommonSubject 3
CoreSubject 1
 
Last edited:
Upvote 0
Welcome to the Board!


Excel Workbook
ABCDE
1TypeSubjectTypeSubject
2BasicSubject 1BasicSubject 1
3BasicSubject 3BasicSubject 3
4CommonSubject 2CommonSubject 2
5CoreSubject 1CommonSubject 3
6CommonSubject 3
7CoreSubject 1
8
9
10
sheet1


Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself
 
Upvote 0
Or with a normal formula


Excel 2013/2016
ABCDE
1TypeSubjectTypeSubject
2BasicSubject 1BasicSubject 1
3BasicSubject 3BasicSubject 3
4CommonSubject 2CommonSubject 2
5CoreSubject 1CommonSubject 3
6CommonSubject 3
7CoreSubject 1
Template
Cell Formulas
RangeFormula
D2=IFERROR(INDEX(A$2:A$7,AGGREGATE(15,6,ROW($A$2:$A$7)-ROW($A$2)+1/($A$2:$A$7={"Basic","Common"}),ROWS($1:1))),"")
E2=IFERROR(INDEX(B$2:B$7,AGGREGATE(15,6,ROW($A$2:$A$7)-ROW($A$2)+1/($A$2:$A$7={"Basic","Common"}),ROWS($1:1))),"")
 
Upvote 0

Forum statistics

Threads
1,214,904
Messages
6,122,169
Members
449,070
Latest member
webster33

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