Filter based on multiple conditions but stop once one is met

naninamu

New Member
Joined
Sep 21, 2023
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi, someone asked me at work if it's possible to set up multiple advanced filtering conditions, but only to apply them u

For instance, say I had a table with the headers Fruit and Colour and Country

In advanced filtering, I set out my conditions:

1) Fruit must be an apple or orange
2) Fruit must be red
3) Fruit must be from Australia

Say nothing matches condition 1), so it then looks at condition 2. It finds red fruit, so it ONLY FILTERS THE TABLE BASED ON THIS, even though there is non-red Australian fruit in the table.

ie - it has stopped filtering as a true condition was found.

I have no idea if this can be done through Advanced Filtering, a formula or something else I don't know about - can anyone help?

Thanks!!
 

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
Receip.xlsm
BCDEF
2FruitColourCountaryApple
3AppleRedAustariaRed
4AppleRedAustariaAustaria
5AppleBlackAustariaOrange
6OrangeRedAustaria
7
8
9AppleRedAustaria
10AppleRedAustaria
11OrangeRedAustaria
12
4
Cell Formulas
RangeFormula
B9:D11B9=FILTER(B2:D8,((B2:B8=F2)+(B2:B8=F5))*(C2:C8=F3)*(D2:D8=F4))
Dynamic array formulas.
 
Upvote 0
Try this VBA option on a copy of your worksheet (tested on the table shown)
VBA Code:
Sub Halting_Filter()
    Dim ws As Worksheet
    Set ws = Worksheets("Sheet1")       '<-- *** Change to actual sheet name ***
    If ws.AutoFilterMode Then ws.AutoFilter.ShowAllData
    With ws.Range("A1").CurrentRegion
        .AutoFilter 1, "apple", 2, "orange"
        .AutoFilter 2, "red"
        If .SpecialCells(xlCellTypeVisible).Address = .Rows(1).Address Then
            ws.AutoFilter.ShowAllData
                .AutoFilter 2, "red"
            Else
                .AutoFilter 3, "Australia"
            If .SpecialCells(xlCellTypeVisible).Address <> .Rows(1).Address Then
                .AutoFilter 3, "Australia"
            End If
        End If
    End With
End Sub

Book1
ABC
1FruitColourCountry
2AppleRedAustralia
3OrangeOrangeUK
4BananaYellowUSA
5AppleRedNew Zealand
6OrangeOrangeKorea
7BananaYellowUSA
8AppleRedAustralia
9OrangeOrangeKorea
Sheet1


Book1
ABC
1FruitColourCountry
2AppleRedAustralia
8AppleRedAustralia
10
Sheet1
 
Upvote 0
Another option to try:
I'm using @kevin9999 example, but the result is different.
VBA Code:
Sub naninamu_1()

With Range("A1").CurrentRegion
    .AutoFilter
    If WorksheetFunction.CountIf(.Columns(1), "apple") + WorksheetFunction.CountIf(.Columns(1), "orange") > 0 Then
        .AutoFilter Field:=1, Criteria1:="apple", Operator:=xlOr, Criteria2:="orange"
    
    ElseIf WorksheetFunction.CountIf(.Columns(2), "red") > 0 Then
        .AutoFilter Field:=2, Criteria1:="red"
    
    ElseIf WorksheetFunction.CountIf(.Columns(3), "Australia") > 0 Then
        .AutoFilter Field:=3, Criteria1:="Australia"
    End If

End With
End Sub

Book1
ABC
1FruitColourCountry
2AppleRedAustralia
3OrangeOrangeUK
4BananaYellowUSA
5AppleRedNew Zealand
6OrangeOrangeKorea
7BananaYellowUSA
8AppleRedAustralia
9OrangeOrangeKorea
Sheet2


Result:
Book1
ABC
1FruitColourCountry
2AppleRedAustralia
3OrangeOrangeUK
5AppleRedNew Zealand
6OrangeOrangeKorea
8AppleRedAustralia
9OrangeOrangeKorea
Sheet2
 
Upvote 0
Thank you everyone for your suggestions. I will need to take some time to understand and how it all works, but appreciate both of your help with my problem! :)
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,183
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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