Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
To test each of the sample macros in this article, use the following sample
data:
A1: Name B1: Zone C1: Amount
A2: bob B2: a C2: 3
A3: sue B3: c C3: 2
A4: mary B4: a C4: 6
A5: pete B5: b C5: 1
A6: paul B6: b C6: 4
Macro with "OR" Criteria for One Field
The following sample macro displays the records in the list where the items in the Zone field are either "a" or "b".
Sub Custom1()
Range("A1").AutoFilter Field:=2, Criteria1:="a", Operator:=xlOr, _
Criteria2:="b"
End Sub
If you run this macro from the sheet that contains the sample list in this article, your list shows all records, except row 3.
Macro to Turn Off the AutoFilter
The following sample macro turns off the AutoFilter, assuming it is turned on, and displays all the records in the list.
NOTE: If the AutoFilter is not on when this macro runs, the macro turns on the AutoFilter, but because no criteria is specified, all records should still appear.
Sub Clear_Filter()
Range("A1").AutoFilter
End Sub
Macro with "AND" Criteria for One Field
The following sample macro displays the records in the list where the items in the Amount field are greater than or equal to one, but less than four:
Sub Custom2()
Range("A1").AutoFilter Field:=3, Criteria1:=">=1", _
Operator:=xlAnd, Criteria2:="<4"
End Sub
If you run this macro from the sheet that contains the sample list, rows 2,
3, and 5 appear.
Macro with Criteria for Two Fields
The following sample macro specifies criteria for two fields:
Sub Custom3()
Range("A1").AutoFilter Field:=2, Criteria1:="a"
Range("A1").AutoFilter Field:=3, Criteria1:="3"
End Sub
If you run this macro from the sheet that contains the sample list, only row 2 appears.