Storing multiple values from a list box

  • Thread starter Thread starter Guest
  • Start date Start date
G

Guest

I have a form that has a subform. In both the form and subform I would like
to have a multi-select list box. I created a many-to-many relationship to
allow me to store the values in the list box. However, I do not know how to
get the value in the list box to be stored in the many-to-many table. What
will the control source be for this field?
 
OR, can I use VB code to do this? If so, what event should be used and how
would this be done? Thank you.
 
I have a form that has a subform. In both the form and subform I would like
to have a multi-select list box. I created a many-to-many relationship to
allow me to store the values in the list box. However, I do not know how to
get the value in the list box to be stored in the many-to-many table. What
will the control source be for this field?

You can't do it that simply: a multiselect listbox does not have "a
value" which can be stored in a Control Source.

Instead, you need to use VBA code to move the data from the listbox
into a table (or vice versa). Here's some sample VBA code from one of
my applications for a similar issue - there's a many to many
relationship from Animals to HealthIssues, using AnimalCondition as
the junction table.

Private Sub cmdProcess_Click()
' Comments : Update the AnimalCondition table based on the
' selections in the unbound multiselect listbox lstHealthIssues.
' Newly selected rows will be added to the table, newly cleared
' rows will be deleted.
' Parameters: None
' Modified : 01/29/02 by JWV
'
' --------------------------------------------------
' Populate the AnimalCondition table with the selected issues
On Error GoTo PROC_ERR

Dim iItem As Integer
Dim lngCondition As Long
Dim db As DAO.Database
Dim rs As DAO.Recordset

' save the current record if it's not saved
If Me.Dirty = True Then
Me.Dirty = False
End If
Set db = CurrentDb
' Open a Recordset based on the table
Set rs = db.OpenRecordset("AnimalCondition", dbOpenDynaset)
With Me!lstHealthIssues
' Loop through all rows in the Listbox
For iItem = 0 To .ListCount - 1
lngCondition = .Column(0, iItem)
' Determine whether this AnimalID-HealthID combination is
' in the table
rs.FindFirst "[AnimalID] = " & Me.AnimalID & " AND " _
& "[HealthIssueID] = " & lngCondition
If rs.NoMatch Then ' this item has not been added
If .Selected(iItem) Then
' add it
rs.AddNew
rs!AnimalID = Me.AnimalID
rs!HealthIssueID = lngCondition
rs.Update
End If ' if it wasn't selected, ignore it
Else
If Not .Selected(iItem) Then
' delete this record if it's been deselected
rs.Delete
End If ' if it was selected, leave it alone
End If
Next iItem
End With
rs.Close
Set rs = Nothing
Set db = Nothing
Me.subAnimalCondition.Requery

PROC_EXIT:
Exit Sub

PROC_ERR:
MsgBox "Error " & Err.Number & " in cmdProcess_Click:" _
& vbCrLf & Err.Description
Resume PROC_EXIT

End Sub



John W. Vinson[MVP]
 
Back
Top