Provided by Allen Browne, September 2004
This article explains how to use a multi-select list box to select several items at once, and open a report limited to those items.
With a normal list box or text box, you can limit your report merely by placing a reference to the control in the Criteria row of its query, e.g. [Forms].[MyForm].[MyControl]. You cannot do that with a multi-select list box. Instead, loop through the ItemsSelected collection of the list box, generating a string to use with the IN operator in the WHERE clause of your SQL statement.
This example uses the Products by Category report in the Northwind sample database.
Name | lstCategory | |
Multi Select | Simple | |
Row Source Type | Table/Query | |
Row Source | SELECT Categories.CategoryID, Categories.CategoryName FROM Categories ORDER BY Categories.CategoryName; |
|
Column Count | 2 | |
Column Widths | 0 |
Name | cmdPreview | |
Caption | Preview | |
On Click | [Event Procedure] |
Private Sub cmdPreview_Click() On Error GoTo Err_Handler 'Purpose: Open the report filtered to the items selected in the list box. 'Author: Allen J Browne, 2004. http://allenbrowne.com Dim varItem As Variant 'Selected items Dim strWhere As String 'String to use as WhereCondition Dim strDescrip As String 'Description of WhereCondition Dim lngLen As Long 'Length of string Dim strDelim As String 'Delimiter for this field type. Dim strDoc As String 'Name of report to open. 'strDelim = """" 'Delimiter appropriate to field type. See note 1. strDoc = "Products by Category" 'Loop through the ItemsSelected in the list box. With Me.lstCategory For Each varItem In .ItemsSelected If Not IsNull(varItem) Then 'Build up the filter from the bound column (hidden). strWhere = strWhere & strDelim & .ItemData(varItem) & strDelim & "," 'Build up the description from the text in the visible column. See note 2. strDescrip = strDescrip & """" & .Column(1, varItem) & """, " End If Next End With 'Remove trailing comma. Add field name, IN operator, and brackets. lngLen = Len(strWhere) - 1 If lngLen > 0 Then strWhere = "[CategoryID] IN (" & Left$(strWhere, lngLen) & ")" lngLen = Len(strDescrip) - 2 If lngLen > 0 Then strDescrip = "Categories: " & Left$(strDescrip, lngLen) End If End If 'Report will not filter if open, so close it. For Access 97, see note 3. If CurrentProject.AllReports(strDoc).IsLoaded Then DoCmd.Close acReport, strDoc End If 'Omit the last argument for Access 2000 and earlier. See note 4. DoCmd.OpenReport strDoc, acViewPreview, WhereCondition:=strWhere, OpenArgs:=strDescrip Exit_Handler: Exit Sub Err_Handler: If Err.Number <> 2501 Then 'Ignore "Report cancelled" error. MsgBox "Error " & Err.Number & " - " & Err.Description, , "cmdPreview_Click" End If Resume Exit_Handler End Sub
Home | Index of tips | Top |