VBA Advanced auto filter for multiple columns containing "y" or "n" - goal is to exclude rows w/ "n" in certain columns

tdgvba

New Member
Joined
Jul 8, 2018
Messages
3
Hi, new to VBA and have been having difficulty finding a solution on the following issue and would greatly appreciate any ideas.

Would like to be able to filter the "Data" table based on the following criteria i.e. show all companies that are either "office" or "industrial" or "office" and "industrial."

In other words, the results should exclude/ filter out company "Name 4" with "n" in both "office" and "industrial"

Would prefer not using hide/ unhide rows but not sure if possible to be done with auto filter or advanced filter.

Criteria

OfficeIndsutrialRetail
yyn

<tbody>
</tbody>

Data Table

Company NameOfficeIndustrialRetail
Name 1yyy
Name 2nyy
Name 3ynn
Name 4nnn
Name 5yny

<tbody>
</tbody>

Thank you!
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Welcome to the MrExcel board!

Seems like you want to do this with vba but it could be done manually with Advanced Filter too.
I'm not sure of your exact layout, but for this task there is no need for the criteria cells that you are showing at the top so I have the main table starting in row 1 as shown.


Book1
ABCDE
1Company NameOfficeIndustrialRetail
2Name 1yyy
3Name 2nyy
4Name 3ynn
5Name 4nnn
6Name 5yny
Adv Filter


I am assuming that column E is available to use for a criteria range (just 2 cells). Any other column could easily be used if E is not available.
Code:
Sub AdvFilter()
  Dim rCrit As Range
  
  Set rCrit = Range("E1:E2")
  rCrit.Cells(2).Formula = "=OR(B2=""y"",C2=""y"")"
  Range("A1", Range("D" & Rows.Count).End(xlUp)).AdvancedFilter Action:=xlFilterInPlace, CriteriaRange:=rCrit, Unique:=False
End Sub

My sheet after running the code:


Book1
ABCDE
1Company NameOfficeIndustrialRetail
2Name 1yyyTRUE
3Name 2nyy
4Name 3ynn
6Name 5yny
Adv Filter
Cell Formulas
RangeFormula
E2=OR(B2="y",C2="y")
 
Last edited:
Upvote 0
Thank you so much, Peter. Greatly appreciated and is giving me an idea how I could potentially achieve what I am looking for. The reason for the criteria, I should have made it clear, is that I want it to be dynamic i.e be able to change the search to "industrial" only for example or "office" and "retail" or "office", "industrial" and "retail"...

Again, much appreciated.
 
Upvote 0
The reason for the criteria, I should have made it clear, is that I want it to be dynamic i.e be able to change the search to "industrial" only for example or "office" and "retail" or "office", "industrial" and "retail"...
OK, let's try another approach then. First though, are you aware that for criteria set up like this, criteria entered on the same row are AND criteria? If you want an OR condition you need to put the criteria on separate rows. Further information here if you need it. The set up below then is filtering for (Office = y AND Retail = y) OR (Industrial = y)


Book1
ABCD
1Company NameOfficeIndustrialRetail
2yy
3y
4
5
6
7Company NameOfficeIndustrialRetail
8Name 1yyy
9Name 2nyy
12Name 5yny
13
Adv Filter



Try this Worksheet_Change event code for the layout I have shown. Post back if you cannot adapt to your layout or if you need details of how to implement this event code.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim rCrit As Range, rData As Range
  
  Set rData = Range("A7").CurrentRegion
  If Not Intersect(Target, Range("A1:D5")) Is Nothing Then
    Set rCrit = Range("A1").CurrentRegion
    If rCrit.Rows.Count = 1 Then
      If ActiveSheet.FilterMode Then ActiveSheet.ShowAllData
    Else
      rData.AdvancedFilter Action:=xlFilterInPlace, CriteriaRange:=rCrit, Unique:=False
    End If
  End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,952
Messages
6,122,458
Members
449,085
Latest member
ExcelError

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