How to extract and list all values from table range that meet certain criteria

AmroK

New Member
Joined
Jan 25, 2022
Messages
12
Office Version
  1. 365
Platform
  1. Windows
Hi guys, I've spent the last few hours trying to find a solution for this, but no luck. Really hoping someone can help?

I have a table that I've generated using a bunch of array look up formulas. The list contains ID's in a table format as per the below.

I need to be able to use a formula which would use the table to find all ID's that start with "MEN" or "AEF" or "SUB" and list those ID's in a separate column.

I'm generating this list so that I can then use it to filter another large (structured) table that contains all of these ID's under 1 heading.

I tried various array formulas with no success. I would also ideally like to do this without using VBA or Marco.

Any ideas please?

Using Excel in Office 365 on Windows.
 

Attachments

  • 2022-01-25_20-28-32.png
    2022-01-25_20-28-32.png
    19.9 KB · Views: 21

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Hi & welcome to MrExcel.
How about
Excel Formula:
=LET(rng,B1:L21,r,ROWS(rng),s,SEQUENCE(r*COLUMNS(rng),,0),I,INDEX(rng,MOD(s,r)+1,INT(s/r)+1),FILTER(I,(LEFT(I,3)="MEN")+(LEFT(I,3)="sub")+(LEFT(I,3)="AEF")))
 
Upvote 0
Solution
Welcome to the MrExcel Message Board!

Cross-posting (posting the same question in more than one forum) is not against our rules, but the method of doing so is covered by #13 of the Forum Rules.

Be sure to follow & read the link at the end of the rule too!

Cross posted at: How to extract and list all values from table range that meet certain criteria
If you have posted the question at more places, please provide links to those as well.

If you do cross-post in the future and also provide links, then there shouldn’t be a problem.
 
Upvote 0
=LET(rng,B1:L21,r,ROWS(rng),s,SEQUENCE(r*COLUMNS(rng),,0),I,INDEX(rng,MOD(s,r)+1,INT(s/r)+1),FILTER(I,(LEFT(I,3)="MEN")+(LEFT(I,3)="sub")+(LEFT(I,3)="AEF")))
Worked perfectly!!!

Thank you so much!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,234
Messages
6,170,891
Members
452,366
Latest member
TePunaBloke

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