Using partial match with filter and vstack

corey338

New Member
Joined
Feb 26, 2024
Messages
4
Office Version
  1. 365
Platform
  1. Windows
All:

With help from some of this site's suggestions, I've got the following formula to pull from several worksheets:

=FILTER(VSTACK(FRR:SOD!G3:M200),(VSTACK(FRR:SOD!K3:K200)<>"")*(VSTACK(FRR:SOD!K3:K200)="ABC XXXX"))

Instead of looking for an exact match to "ABC XXXX", Is there a way to filter for a partial match to just "ABC"? Think of "ABC" as a location, and "XXXX" as a job/position at that location. In the columns across my 10 worksheets "ABC" is constant, but there are multiple variations to the "XXXX" in all the cells and these designations cannot be altered at this point. I would like to be able to pull everyone assigned to "ABC" to a new worksheet then filter by "XXXX" job/position. Is that possible?

I appreciate any help you all can provide.

Thanks!
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
how about

=FILTER(VSTACK(FRR:SOD!G3:M200),(VSTACK(FRR:SOD!K3:K200)<>"")*(VSTACK(Left(FRR:SOD!K3:K200,3))="ABC"))
 
Upvote 0
Hi & welcome to MrExcel.
Another option
Excel Formula:
=FILTER(VSTACK(FRR:SOD!G3:M200),left(VSTACK(FRR:SOD!K3:K200),3)="ABC")
 
Upvote 0
how about

=FILTER(VSTACK(FRR:SOD!G3:M200),(VSTACK(FRR:SOD!K3:K200)<>"")*(VSTACK(Left(FRR:SOD!K3:K200,3))="ABC"))
Thanks for the suggestion, but I couldn't get this to work. Kept getting the #CALC! error message.
 
Upvote 0
did you try Fluff function ?
calc usually means the criteria is not met
 
Upvote 0
Hi & welcome to MrExcel.
Another option
Excel Formula:
=FILTER(VSTACK(FRR:SOD!G3:M200),left(VSTACK(FRR:SOD!K3:K200),3)="ABC")
This one worked! It's giving me exactly what I need to filter. For my education, what is the purpose of the "3" in the formula? Just so I can have a better insight in the future. Thanks for your help!
 
Upvote 0
take the 3 characters starting from the left
LEFT( Cell, Number of characters from left)
HENCE in your case its ABC
 
Upvote 0
take the 3 characters starting from the left
LEFT( Cell, Number of characters from left)
HENCE in your case its ABC
Great, that's what I was thinking. So if I have similar cell structure where I need to isolate "ABCD", I would use "4" instead...
 
Upvote 0
I'm surprised mine worked, but etaf's didn't. The only difference is the (VSTACK(FRR:SOD!K3:K200)<>"") portion which isn't needed.
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
Members
452,361
Latest member
d3ad3y3

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