ACC: How to Filter a Report from a Pop-Up FormID: Q147143
|
Moderate: Requires basic macro, coding, and interoperability skills.
This article describes how to filter a report dynamically in Print Preview
by selecting filter criteria from a pop-up form.
NOTE: This article explains a technique demonstrated in the sample
files, RptSampl.exe (for Microsoft Access for Windows 95 version 7.0)
and RptSmp97.exe (for Microsoft Access 97). For information about how
to obtain these sample files, please see the following articles in the
Microsoft Knowledge Base:
Q145777 ACC95: Microsoft Access Sample Reports Available on MSL
Q175072 ACC97: Microsoft Access 97 Sample Reports Available on MSL
The technique involves creating a pop-up form and a report in the sample database Northwind. The form enables you to choose which fields and values to use for filtering a report in Print Preview.
CompanyName
ContactName
City
Region
Country
Form: frmFilter
---------------------
ScrollBars: Neither
RecordSelectors: No
NavigationButtons: No
PopUp: Yes
BorderStyle: Thin
MinMaxButtons: None
Width: 2.5"
Private Sub Form_Open(Cancel As Integer)
DoCmd.OpenReport "rptCustomers", A_PREVIEW 'Open Customers report.
DoCmd.Maximize 'Maximize the report window.
End Sub
Private Sub Form_Close()
DoCmd.Close acReport, "rptCustomers" 'Close the Customers report.
DoCmd.Restore 'Restore the window size
End Sub
Combo box:
Name: Filter1
Tag: CompanyName
RowSource: Select Distinct [CompanyName] from Customers Order _
By [CompanyName];
Width: 1.5"
Combo Box:
Name: Filter2
Tag: ContactName
RowSource: Select Distinct [ContactName] from Customers Order _
By [ContactName];
Width: 1.5"
Combo Box:
Name: Filter3
Tag: City
RowSource: Select Distinct [City] from Customers Order By [City];
Width: 1.5"
Combo Box:
Name: Filter4
Tag: Region
RowSource: SELECT DISTINCT Customers.Region FROM Customers _
WHERE(((Customers.Region) Is Not Null)) ORDER BY _
Customers.Region;
Width: 1.5"
Combo Box:
Name: Filter5
Tag: Country
RowSource: Select Distinct [Country] from Customers Order _
By [Country];
Width: 1.5"
Command button:
Name: Clear
Caption: Clear
OnClick: [Event procedure]
Set the OnClick [Event procedure] as follows:
Private Sub Clear_Click()
Dim intCounter as Integer
For intCounter = 1 To 5
Me("Filter" & intCounter) = ""
Next
End Sub
Command Button:
Name: Set Filter
Caption: Set Filter
OnClick: [Event procedure]
Set the OnClick [Event procedure] as follows:
Private Sub Set_Filter_Click()
Dim strSQL as String, intCounter as Integer
' Build SQL String.
For intCounter = 1 To 5
If Me("Filter" & intCounter) <> "" Then
strSQL = strSQL & "[" & Me("Filter" & intCounter).Tag & "] " _
& " = " & Chr(34) & Me("Filter" & intCounter) & Chr(34) & " _
And "
End If
Next
If strSQL <> "" Then
' Strip Last " And ".
strSQL = Left(strSQL, (Len(strSQL) - 5))
' Set the Filter property.
Reports![rptCustomers].Filter = strSQL
Reports![rptCustomers].FilterOn = True
End If
End Sub
Command Button:
Name: Close
Caption: Close
OnClick: [Event procedure]
Set the OnClick [Event procedure] as follows:
Private Sub Close_Click()
DoCmd.Close acForm, Me.Form.Name
End Sub
For more information about the Filter property, search the Help Index for
"Filter Property," or ask the Microsoft Access 97 Office Assistant.
For more information about filter by form or filter by selection, search
the Help Index for "Filter By Form" or "Filter By Selection," or ask the
Microsoft Access 97 Office Assistant.
Additional query words: dynamic popup
Keywords : FmrHowto RptSort
Version : 7.0 97
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: April 16, 1999