473,587 Members | 2,267 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

How do I filter a Listbox with multiple comboboxes?

33 New Member
I have a Form with four comboboxes (cboSelectDepar tment, cboSelectOperat ion, cboSelectModel and cboSelectVarian t), a Listbox (selectionList) and a Button (cmdSelectStep) .

The Listbox displays a StepID (number) and a StepName (text).I want to filter the Listbox based upon the values in the comboboxes. After each combobox selection the List becomes shorter and shorter.

Next, the user selects a StepID number from the Listbox and presses the Button to set a Temporary Variable (StepRecord).

To make things complicated: The combobox cboSelectOperat ion is Cascaded from cboSelectDepart ment and cboSelectVarian t is Cascaded from cboSelectModel. So I the user selects a Department, the Operation combobox list is limited, the same with Model and Variants.

I've found a tutorial database ("Cascading Combo Boxes") where all the comboboxes are cascaded. Next, I've copied the code and adapted it to my database. But now I'm stuck with the SQL code for filtering (see Private Sub filterList()). This is the code I have now:


Expand|Select|Wrap|Line Numbers
  1. Option Compare Database
  2. Option Explicit
  3.  
  4. Private Sub filterList()
  5.     Dim strRS As String
  6.  
  7.   ' Filter the list box appropriately based on the combo box selection(s)
  8.   strRS = "SELECT qryFilterList.StepID, qryFilterList.StepName FROM qryFilterList"
  9.  
  10.   If Not IsNull(Me.cboSelectVariant) Then
  11.     strRS = strRS & " WHERE VariantID = " & Me.cboSelectVariant
  12.   ElseIf Not IsNull(Me.cboSelectModel) Then
  13.     strRS = strRS & " WHERE ModelID = " & Me.cboSelectModel
  14.   ElseIf Not IsNull(Me.cboSelectOperation) Then
  15.     strRS = strRS & " WHERE OperationID = " & Me.cboSelectOperation
  16.   ElseIf Not IsNull(Me.cboSelectDepartment) Then
  17.     strRS = strRS & " WHERE DeptID = " & Me.cboSelectDepartment
  18.   End If
  19.  
  20.   strRS = strRS & " ORDER BY qryFilterList.StepName;"
  21.   Me.selectionList.RowSource = strRS
  22.   Me.selectionList.Requery
  23. End Sub
  24.  
  25. Private Sub cboSelectDepartment_AfterUpdate()
  26.  
  27.   Me.cboSelectOperation.RowSource = "SELECT tblOperations.OperationID,tblOperations.Operation, tblOperations.Description FROM tblOperations " & _
  28.      " WHERE DeptID = " & Nz(Me.cboSelectDepartment) & _
  29.      " ORDER BY Operation"
  30.   Me.cboSelectOperation = Null
  31.   filterList
  32. End Sub
  33.  
  34. Private Sub cboSelectModel_AfterUpdate()
  35.  
  36.   Me.cboSelectVariant.RowSource = "SELECT qryVariant.variantID, qryVariant.Variant FROM qryVariant " & _
  37.      " WHERE ModelID = " & Nz(Me.cboSelectModel) & _
  38.      " ORDER BY Variant"
  39.   Me.cboSelectVariant = Null
  40.   filterList
  41. End Sub
  42.  
  43. Private Sub cboSelectOperation_AfterUpdate()
  44.   filterList
  45. End Sub
  46.  
  47. Private Sub cboSelectVariant_AfterUpdate()
  48.   filterList
  49. End Sub
  50.  
  51. Private Sub Form_Load()
  52.   filterList
  53.   Me.selectionList.RowSource = ""
  54. End Sub
  55.  
  56. Private Sub EnableControls()
  57.  
  58.   ' Clear the combo boxes
  59.   If IsNull(Me.cboSelectDepartment) Then
  60.      Me.cboSelectOperation = Null
  61.   End If
  62.  
  63.   If IsNull(Me.cboSelectOperation) Then
  64.     Me.cboSelectModel = Null
  65.   End If
  66.  
  67.   If IsNull(Me.cboSelectModel) Then
  68.     Me.cboSelectVariant = Null
  69.   End If
  70.  
  71.   ' Enable or disable combo boxes based on whether the combo box preceeding it has a value.
  72.   Me.cboSelectOperation.Enabled = (Not IsNull(Me.cboSelectDepartment))
  73.   Me.cboSelectModel.Enabled = (Not IsNull(Me.cboSelectOperation))
  74.   Me.cboVariant.Enabled = (Not IsNull(Me.cboSelectModel))
  75. End Sub
This code partially works! If I select from the Department and Operation comboboxes the List is filtered properly. But when I select a Model, the Department and Operation filter is removed/ignored.

I think I need to put a AND operator in the SQL part to combine all the filters. Unfortunately I don't have any experience with creating a SQL code. Can yo guys help me or point me in the right direction?

Thanks!
Nov 7 '14 #1
2 5946
MikeTheBike
639 Recognized Expert Contributor
Hi

This is completly air code but should be somewhere near
Expand|Select|Wrap|Line Numbers
  1. Private Sub filterList()
  2.     Dim strRS As String
  3.  
  4.     ' Filter the list box appropriately based on the combo box selection(s)
  5.     If Me.cboSelectVariant.ListIndex >= 0 Then strRS = strRS & " AND VariantID = " & Me.cboSelectVariant
  6.  
  7.     If Me.cboSelectModel.ListIndex >= 0 Then strRS = strRS & " AND ModelID = " & Me.cboSelectModel
  8.  
  9.     If Me.cboSelectOperation.ListIndex >= 0 Then strRS = strRS & " AND OperationID = " & Me.cboSelectOperation
  10.  
  11.     If Me.cboSelectDepartment.ListIndex >= 0 Then strRS = strRS & " AND DeptID = " & Me.cboSelectDepartment
  12.  
  13.  
  14.     'IF FILTER FOUND ADD 'WHERE' AND REMOVE LEADING 'AND' (IF NOT FOUND IT WILL REMAIN A NULL STRING)
  15.     If strRS <> "" Then strRS = " WHERE " & Mid(strRS, 6)
  16.  
  17.     'ADD FILTER TO QUERY
  18.     strRS = "SELECT qryFilterList.StepID, qryFilterList.StepName FROM qryFilterList " & strRS
  19.  
  20.     'ADD ORDER BY CLAUSE
  21.     strRS = strRS & " ORDER BY qryFilterList.StepName;"
  22.  
  23.  
  24.     Me.selectionList.RowSource = strRS
  25.     Me.selectionList.Requery
  26. End Sub
I have used the 'ListIndex' property, which is -1 if nothing is selected, instead of Not IsNull()

It also assumes all criteria are numeric.

HTH


MTB
Nov 7 '14 #2
Jeroen3131
33 New Member
Hey Mike,

The code works Flawless! It's exactly what I wanted!

Thank you.
Nov 7 '14 #3

Sign in to post your reply or Sign up for a free account.

Similar topics

1
518
by: Alex Fimine | last post by:
Hi, I have a list box lstMy which is bound to a datatable dt. The SelectionMode in the listbox is set to MultiSimple. I want to run through the listbox and return all _values_ from the selected items. In other words, if it were to be a single select listbox i would just refer to it as lstMy.SelectedValue however in the multiple select I...
3
26651
by: RRT | last post by:
I have an existing table which describes Streets and sections of streets between intersections: Table 1: Streets by Intersections Street Area Ann St. Main to Jackson Ann. St. Jackson To Summer Ann St. Summer to End Joe St. Aberdeen to Mike and so on for 1200 records
4
6755
by: Lucas Tam | last post by:
Hi all, Does anyone have an example on how to populate a Listbox with Text, a ComboBox Control, and a Checkbox control? Basically I want my listbox to look like this: Some Text More Text
0
2759
by: marcelo | last post by:
Could you help me out here. I need to accomplish this: I need to filter listbox items from by entering some characters to the textbox. But the problem is that items (files that are read from directory) in the listbox has the same name in the beginning, for example '2007_<docNo>_<CustomerName_ItemSold>.doc'. And the information I need to find...
2
11442
by: Matt | last post by:
Hi all, me again! :) I've now got an issue with combo boxes. Basically, I have a number of items that I want a user to pick from a single list. It's basically along the lines of: Fruit 1: Fruit 2: Fruit 3:
3
1861
by: Randy | last post by:
I have a routine that creates a series of comboboxes, each of which is bound to a common dataview. Everything used to work fine, but now, when I change the value of any of the comboboxes, the value in ALL of the comboboxes changes to the new value. I have boiled down the code to the simplest lines and placed it on its own form, but I still...
1
2856
by: Redbeard | last post by:
Hi, I am a newbie using Access 2003 and I am trying to select multiple values from a list box and put them in a text box on the same Form. The closest thing in the form pages that I can find is some code from an old post that select multiple values from a list box and put them in a text box on the another Form. I assume that this code runs off a...
0
1388
by: Gunnar Hurtig | last post by:
Hi All I am relatively new to Tkinter and am putting a wraparound to the ATNF ASAP program. In one part I present several long lists in list boxes for selection. My code will remember the multiple selections made but I woul also like to highlight and maintain the highlighted items as I make additional selections. I can maintain the highlighted...
3
6420
by: mbedford | last post by:
I'm creating an asset/employee/everything including the kitchen sink database for my office. Currently I'm working on formEmployee. It contains a listbox which contains all the employees, and fields for the employee details which populate by the selection in the listbox. The listbox (listEmployee) has a query rowsource (qryEmployees). ...
1
4293
by: rafeenatnat | last post by:
Hi, I can only bind 1 item even if I selected more than 1 item from my ListBox. Every time I select another item, my uniformGrid(grid to display selected items) will only display the first selection not the other selected items. My uniformGrid has 2 rows and 2 columns. I just want to fill them with my selected items(i.e. image) from my...
0
7915
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However, people are often confused as to whether an ONU can Work As a Router. In this blog post, we’ll explore What is ONU, What Is Router, ONU & Router’s main...
0
8205
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers, it seems that the internal comparison operator "<=>" tries to promote arguments from unsigned to signed. This is as boiled down as I can make it. ...
1
7967
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows Update option using the Control Panel or Settings app; it automatically checks for updates and installs any it finds, whether you like it or not. For...
0
8220
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each protocol has its own unique characteristics and advantages, but as a user who is planning to build a smart home system, I am a bit confused by the...
1
5712
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new presenter, Adolph Dupré who will be discussing some powerful techniques for using class modules. He will explain when you may want to use classes...
0
3840
by: TSSRALBI | last post by:
Hello I'm a network technician in training and I need your help. I am currently learning how to create and manage the different types of VPNs and I have a question about LAN-to-LAN VPNs. The last exercise I practiced was to create a LAN-to-LAN VPN between two Pfsense firewalls, by using IPSEC protocols. I succeeded, with both firewalls in...
0
3872
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
2347
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated we have to send another system
1
1452
muto222
by: muto222 | last post by:
How can i add a mobile payment intergratation into php mysql website.

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.