Filter continuous form with comboboxes and a listbox

Danick

Registered User.
Local time
Today, 01:41
Joined
Sep 23, 2008
Messages
371
I'm using Allen Browne's search criteria to filter a continuous form - found here:

http://allenbrowne.com/ser-62.html

But I'm struggling in changing one of the text boxes to a list box.

For instance, Allen had the txtFilterCity as:

Code:
'Text field example. Use quotes around the value in the string.
    If Not IsNull(Me.txtFilterCity) Then
        strWhere = strWhere & "([City] = """ & Me.txtFilterCity & """) AND "
    End If

So I changed the text box to a list box, called it lstFilterCity and have this

Code:
 If Not IsNull(Me.lstFilterCity) Then
        strWhere = strWhere & "([City] = """ & Me.lstFilterCity & """) AND "
    End If

This works when the listbox is not multiselect, but I can't make it work when I change it to a simple multiselect list box.

Anyone have a sample of how to modify the code to include a multiselect listbox in the search criteria to filter a continuous form?
 
Last edited:
This isn't doing exactly that, but you can adapt the multiselect code:

http://www.baldyweb.com/multiselect.htm

I've tried many different ways to try to adapt this to work. But I keep getting errors. This last one in the baldyweb example, I tried to replace just

Code:
If Not IsNull(Me.lstFilterCity) Then
        strWhere = strWhere & "([City] = """ & Me.lstFilterCity & """) AND "
    End If

with

Code:
Dim ctl As Control
Dim varItem As Variant

'add selected values to string
Set ctl = Me.lstFilterCity
For Each varItem In ctl.ItemsSelected
  strWhere = strWhere & ctl.ItemData(varItem) & ","
  'Use this line if your value is text
  'strWhere = strWhere & "'" & ctl.ItemData(varItem) & "',"
Next varItem
'trim trailing comma
strWhere = Left(strWhere, Len(strWhere) - 1)

And this produces a Run-time error '5':
Invalid procedure call or argument.


Here's the whole code from Allen's cmdFilter

Code:
Private Sub cmdFilter_Click()
    'Purpose:   Build up the criteria string form the non-blank search boxes, and apply to the form's Filter.
    'Notes:     1. We tack " AND " on the end of each condition so you can easily add more search boxes; _
                        we remove the trailing " AND " at the end.
    '           2. The date range works like this: _
                        Both dates      = only dates between (both inclusive. _
                        Start date only = all dates from this one onwards; _
                        End date only   = all dates up to (and including this one).
    Dim strWhere As String                  'The criteria string.
    Dim lngLen As Long                      'Length of the criteria string to append to.
    Const conJetDate = "\#mm\/dd\/yyyy\#"   'The format expected for dates in a JET query string.
    
    '***********************************************************************
    'Look at each search box, and build up the criteria string from the non-blank ones.
    '***********************************************************************
    'Text field example. Use quotes around the value in the string.
    
'This was the original code using a text box *********
  '  If Not IsNull(Me.txtFilterCity) Then
  '      strWhere = strWhere & "([City] = """ & Me.txtFilterCity & """) AND "
  '  End If
 '**********************
    
'This is with the text box changed to a list box.  It's working but only when listbox is not multiselect
'    If Not IsNull(Me.lstFilterCity) Then
'        strWhere = strWhere & "([City] = """ & Me.lstFilterCity & """) AND "
'    End If
'*********************
    
' This is trying to adapt the code from "http://www.baldyweb.com/multiselect.htm" without success
'Produces a runtime error

Dim ctl As Control
Dim varItem As Variant

'add selected values to string
Set ctl = Me.lstFilterCity
For Each varItem In ctl.ItemsSelected
  strWhere = strWhere & ctl.ItemData(varItem) & ","
  'Use this line if your value is text
  'strWhere = strWhere & "'" & ctl.ItemData(varItem) & "',"
Next varItem
'trim trailing comma
strWhere = Left(strWhere, Len(strWhere) - 1)

'********************************
    
    
  
    'Another text field example. Use Like to find anywhere in the field.
    If Not IsNull(Me.txtFilterMainName) Then
        strWhere = strWhere & "([MainName] Like ""*" & Me.txtFilterMainName & "*"") AND "
    End If
    
    'Number field example. Do not add the extra quotes.
    If Not IsNull(Me.cboFilterLevel) Then
        strWhere = strWhere & "([LevelID] = " & Me.cboFilterLevel & ") AND "
    End If
    
    'Yes/No field and combo example. If combo is blank or contains "ALL", we do nothing.
    If Me.cboFilterIsCorporate = -1 Then
        strWhere = strWhere & "([IsCorporate] = True) AND "
    ElseIf Me.cboFilterIsCorporate = 0 Then
        strWhere = strWhere & "([IsCorporate] = False) AND "
    End If
    
    'Date field example. Use the format string to add the # delimiters and get the right international format.
    If Not IsNull(Me.txtStartDate) Then
        strWhere = strWhere & "([EnteredOn] >= " & Format(Me.txtStartDate, conJetDate) & ") AND "
    End If
    
    'Another date field example. Use "less than the next day" since this field has times as well as dates.
    If Not IsNull(Me.txtEndDate) Then   'Less than the next day.
        strWhere = strWhere & "([EnteredOn] < " & Format(Me.txtEndDate + 1, conJetDate) & ") AND "
    End If
    
    '***********************************************************************
    'Chop off the trailing " AND ", and use the string as the form's Filter.
    '***********************************************************************
    'See if the string has more than 5 characters (a trailng " AND ") to remove.
    lngLen = Len(strWhere) - 5
    If lngLen <= 0 Then     'Nah: there was nothing in the string.
        MsgBox "No criteria", vbInformation, "Nothing to do."
    Else                    'Yep: there is something there, so remove the " AND " at the end.
        strWhere = Left$(strWhere, lngLen)
        'For debugging, remove the leading quote on the next line. Prints to Immediate Window (Ctrl+G).
        'Debug.Print strWhere
        
        'Finally, apply the string as the form's Filter.
        Me.Filter = strWhere
        Me.FilterOn = True
    End If
End Sub
 
Well, you'd want to include the AND since Allen does:

strWhere = Left(strWhere, Len(strWhere) - 1) & " AND "

Also, I'd use a different variable for this, and then add it to strWhere. It doesn't add cleanly to strWhere. Something like:

Code:
Dim ctl As Control
Dim varItem As Variant
Dim strListbox As String

'add selected values to string
Set ctl = Me.lstFilterCity
For Each varItem In ctl.ItemsSelected
  strListbox = strListbox & ctl.ItemData(varItem) & ","
  'Use this line if your value is text
  'strListbox = strListbox & "'" & ctl.ItemData(varItem) & "',"
Next varItem
'trim trailing comma
strListbox = "City In(" & Left(strListbox , Len(strListbox) - 1) & ")"

strWhere = strWhere & strListbox & " AND "
 
So now I'm getting and error 2448 "Can't assign a value to this object" when picking from the list box and still getting an invalid procedure call if I select any of the other boxes
 
Can you attach the db here to test with?
 
Works without error once you switch to the line I said to use if the value is text, which yours is:

Code:
For Each varItem In ctl.ItemsSelected
  'strListbox = strListbox & ctl.ItemData(varItem) & ","
  'Use this line if your value is text
  strListbox = strListbox & "'" & ctl.ItemData(varItem) & "',"
Next varItem
 
Geez, am I too slow?

Danick, I missed that you also need to test if anything was selected:

Code:
    Set ctl = Me.lstFilterCity
    If ctl.ItemsSelected.Count > 0 Then
        For Each varItem In ctl.ItemsSelected
            'strListbox = strListbox & ctl.ItemData(varItem) & ","
            'Use this line if your value is text
            strListbox = strListbox & "'" & ctl.ItemData(varItem) & "',"
        Next varItem
        'trim trailing comma
        strListbox = "[City] In(" & Left(strListbox, Len(strListbox) - 1) & ")"

        strWhere = strWhere & strListbox & " AND "
    End If
 

Users who are viewing this thread

Back
Top Bottom