ACC: How to Use a Multi-Select List Box to Filter a Form

Last reviewed: February 4, 1998
Article ID: Q135546
The information in this article applies to:
  • Microsoft Access versions 7.0, 97

SUMMARY

Moderate: Requires basic macro, coding, and interoperability skills.

This article demonstrates two methods for using a multiple selection list box to restrict records in a recordset. These methods are more flexible than other techniques, such as applying a query or an SQL WHERE clause because they enable you to choose at random which records are displayed.

This article assumes that you are familiar with Visual Basic for Applications and with creating Microsoft Access applications using the programming tools provided with Microsoft Access. For more information about Visual Basic for Applications, please refer to your version of the "Building Applications with Microsoft Access" manual.

MORE INFORMATION

Method 1

This method uses the Filter property of a form. It restricts the records in a recordset based on the selected items in a multiple selection list box. This is done by using Visual Basic code for the OnClick event of a command button.

To create this method, follow these steps:

  1. Open the sample database Northwind.mdb.

  2. Create a new, blank form based on the Customers table and open it in Design view.

  3. On the View menu, click Field List and drag the CustomerID and CompanyName fields from the field list to the Detail section of the form.

  4. Add an unbound list box to the form's Detail section and set its properties as follows:

          Name: List0
          Row Source: Customers
          Column Count: 2
          Column Widths: .5";2"
          Multi Select: Extended
          Width: 2.5"
    

  5. Add a command button to the form. Set the Name property to Command2, and set the OnClick property to [Event Procedure]. On the View menu, click Code, and type the following text in the Form module:

          Option Compare Database
          Option Explicit
    

          Private Sub Command2_Click()
    
             Dim Criteria As String
             Dim i As Variant
    
             ' Build criteria string from selected items in list box.
             Criteria = ""
             For Each i In Me![List0].ItemsSelected
                If Criteria <> "" Then
                      Criteria = Criteria & " OR "
                End If
                Criteria = Criteria & "[CustomerId]='" _
                   & Me![List0].ItemData(i) & "'"
             Next i
    
             ' Filter the form using selected items in the list box.
             Me.Filter = Criteria
             Me.FilterOn = True
    
          End Sub
    
    

  6. Open the form in Form view.

  7. Select multiple items in the list box: click the first item, then hold down the CTRL key, and click subsequent items.

  8. Click the command button. Note that the form's recordset is restricted to the records selected in the list box. If you clear the items and click the button again, you remove the filter and restore all the records.

Method 2

This method modifies the Querydef object of a query. It restricts the records in a recordset based on the selected items in a multiple selection list box. This is done by using Visual Basic code for the OnClick event of a command button.

To create this method, follow these steps:

  1. Open the sample database Northwind.mdb.

  2. Create a new query based on the Orders table and include all the fields. Save the query as "MultiSelect Criteria Example."

  3. Create a new, blank form based on the Customers table and open it in Design view.

  4. Add an unbound list box to the form's Detail section and set its properties as follows:

          Name: List0
          RowSource: Customers
          ColumnCount: 2
          ColumnWidths: .5";2"
          Multiselect: Extended
    

  5. Add a command button to the form. Set the Name property to Command4 and set the OnClick property to the following event procedure:

    Note: This example uses the ItemData property to return values from

             the Bound Column of the ListBox. To return a value from a
             column other than the Bound Column use the Column property
             instead of the ItemData property.
    
          Private Sub Command4_Click()
          Dim Q As QueryDef, DB As DATABASE
          Dim Criteria As String
          Dim ctl As Control
          Dim Itm As Variant
    
          ' Build a list of the selections.
          Set ctl = Me![List0]
    
          For Each Itm In ctl.ItemsSelected
             If Len(Criteria) = 0 Then
                Criteria = Chr(34) & ctl.ItemData(Itm) & Chr(34)
             Else
                Criteria = Criteria & "," & Chr(34) & ctl.ItemData(Itm) _
                & Chr(34)
               End If
             Next Itm
    
             If Len(Criteria) = 0 Then
                Itm = MsgBox("You must select one or more items in the_
                list box!", 0,"No Selection Made")
             Exit Sub
             End If
    
          ' Modify the Query.
          Set DB = CurrentDb()
          Set Q = DB.QueryDefs("MultiSelect Criteria Example")
          Q.SQL = "Select * From Orders Where [CustomerID] In(" & Criteria &_
             ");"
          Q.Close
    
          ' Run the query.
          DoCmd.OpenQuery "MultiSelect Criteria Example"
    
          End Sub
    
    

  6. Open the form in Form view.

  7. Select multiple items in the list box by holding down the CTRL key and clicking the different items.

  8. Click the command button. Note that the query is restricted to the selected records in the list box.

REFERENCES

For more information about the MultiSelect property of a list box, search for "MultiSelect property" using the Microsoft Access 97 Help Index.

For more information about the ItemData property of a list box, search for " ItemData property" using the Microsoft Access 97 Help Index.

For more information about the Column property of a list box, search for "Column property" using the Microsoft Access 97 Help Index.

Keywords          : kbusage FmsHowTo FmsCmbo kbfaq
Version           : 7.0 97
Platform          : WINDOWS
Hardware          : x86
Issue type        : kbhowto


================================================================================


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 4, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.