Normally we use Filter settings on Forms/Reports to extract records on specific conditions. This can be achieved in several ways like adding a WHERE Condition (without the clause WHERE) in the parameter setting of the OpenForm Macro Action or in ApplyFilter Action parameter of a Macro or in the Docmd.OpenForm (like

DoCmd.OpenForm "myForm", acNormal, , "EmployeeID Between 5 AND 10" command line in VBA) or Filter by Selection on Form or use a Query as Record Source and so on.

But, it is very unlikely  that someone think of using the Filter Property of a Table directly to filter records when the Table is open in Datasheet View.  If you are working with someone else project and found a table showing only few records in datasheet view but you are told that the table suppose to have hundreds of records in it and want to find out what happened to the rest of the records, then read on.

We will explore how this trick works on a Table, for a change.  If you ever tried to set a Filter condition directly on a Form then you don’t need any extra help to do this on your own.  To try out this we need some ready made data from Northwind.accdb sample database.  You may try it out with your own table as well.

  1. Import the Order Details  Table from Northwind.accdb sample database.
  2. Open the Table in Design view.
  3. Press F4 to display the Property Sheet of the Table.

    Table Filter Property

    Table Property Sheet View

  4. Find the Filter Property and type [Order ID] Between 35 AND 45 into the property (in Access2007). Type [OrderID] Between 10249 AND 10251 in earlier Access Versions.
  5. Set the Filter On Load property value to Yes.
  6. Save and close the Table Structure.
  7. Open the Table in Datasheet View to see the Filter in action.

The output records displayed are only of Order IDs between 35 and 45.  If you design a Quick Form or Report from this Table the Record Source property will be set with an SQL SELECT statement with the WHERE condition inserted from the Filter Property settings from the Table.  But, if you modify the Filter condition on the Table later don’t expect to reflect that change on the Record Source SQL of Report or Form automatically.

Like anything else in Microsoft Access If you would like to automate this through VBA, to change the filter criteria with the click of a button then here it is for you.  But, there is a small problem which I will tell you later so that you will know how important it is.  After all it is about setting a simple filter condition on the Filter Property of the Table Structure.

We can address the Filter Property of a Table in VBA either through the front-door approach or through the back-door method, so to speak.  The front-door approach is addressing the Filter Property through the TableDef.Property.Filter path and the back-door approach is addressing through Container.Documents.Properties.Filter path.  As you can see the second method is little bit lengthy, that is why I call it back-door method.  We will try examples of both methods.

The second approach is very useful when working with Forms or Reports, like taking a list of all Forms/Reports or want to change the name of a Form etc. You can refer an earlier blog post that creates a User-defined Property (Custom Property) to save values in it for opening a Form with last-worked record to continue work from that record onwards, click here to find out more about it.

Example-1:

  1. Copy and Paste the following VBA Code into a Standard Module of your Database.
    Public Function TableFilter1(ByVal OrderStart As Long, ByVal OrderEnd As Long)
    Dim db As Database
    Dim Tbldef As TableDef
    
    Set db = CurrentDb
    
    Set Tbldef = db.TableDefs("Order Details")
    Tbldef.Properties("Filter").Value = "[Order ID] >=" & OrderStart & " AND [Order ID] <=" & OrderEnd
    Tbldef.Properties("FilterOnLoad").Value = True
    db.TableDefs.Refresh
    
    End Function
  2. Run the above sample Code from the Debug Window or from a Command Button Click Event Procedure like the sample run given below:
TableFilter1 35,45

NB: The above Code and sample run is given for Order Details Table of Access2007.  If you are using an earlier Access Version then change the [Order ID] name to [OrderID] (i.e. without a space between Order and ID) and in the sample run type TableFilter1 10249, 10251 instead of 35,45 for OrderID range values.

If you have not tried out the manual filter method explained above or removed the filter criteria setting from the Filter Property then you will run into problems with the above program reporting an Error message stating that the Filter Property not found.

When you implement the VBA method see that an initial criteria setting is set in the Filter property of the Table.  Without the criteria setting the Filter Property will not be visible in VBA.

Example-2:

Copy and Paste the following VBA Code into the Standard VBA Module and run the Code in the same way as Example-1 with different set of OrderIDs:

Public Function TableFilter2(ByVal OrderStart As Long, ByVal OrderEnd As Long)
Dim db As Database, ctr As Container, doc As Document

Set db = CurrentDb

Set ctr = db.Containers("Tables")
Set doc = ctr.Documents("Order Details")
doc.Properties("Filter").Value = "[Order ID] >=" & OrderStart & " AND [Order ID] <=" & OrderEnd
doc.Properties("FilterOnLoad").Value = True
doc.Properties.Refresh

End Function
Technorati Tags: