Multiselect List or Check boxes

S

sparlaman

I've read through some of the posts here and I just can't quite understand
how to do this. I have 3 tables: teachers, subjects, & subjects_to_teachers.
I have relationships established for a many to many relationship btwn
subjects & teachers. I have the base form which shows teacher info. How do I
create a control on this form that allows the user to select all subjects
that apply to a teacher? I would like to use check boxes where the user
checks all that apply but I'm also interested in knowing how to use a
multiselect list box to do the same.

Thanks in advance!!!
sparlaman
 
D

Dirk Goldgar

sparlaman said:
I've read through some of the posts here and I just can't quite understand
how to do this. I have 3 tables: teachers, subjects, &
subjects_to_teachers.
I have relationships established for a many to many relationship btwn
subjects & teachers. I have the base form which shows teacher info. How do
I
create a control on this form that allows the user to select all subjects
that apply to a teacher? I would like to use check boxes where the user
checks all that apply but I'm also interested in knowing how to use a
multiselect list box to do the same.


I've used checkboxes on a subform, but found it cumbersome and fragile.
I've used a multiselect list box effectively, like this:

*** Storing Multiple Selections From A List Box ***

The best way to store multiple items in a single field is not to do it
at all. Instead, use multiple records in a related table to represent
these items. It's a principle of relational database design that a
single field (column) holds only one datum.

An Access subform is designed to display and edit multiple records from
a related table (these records being related to the record currently
displayed on the main form), and does it with no code at all. A list
box isn't designed to do this, but for small "pick-lists" I do like the
multiselect list box. However, you need to use code to read the related
records for each new main record and select the appropriate items in the
list box, and then whenever the list box is updated you need to use code
to update the set of records in the related table.


Here's code from a sample form that represents "family members", with a
list box named "lstHobbies" that represents, for each family member,
that person's hobbies from the list of all possible hobbies.


'----- start of code -----
Option Compare Database
Option Explicit

Private Sub ClearHobbySelections()

Dim intI As Integer

With Me.lstHobbies
For intI = (.ItemsSelected.Count - 1) To 0 Step -1
.Selected(.ItemsSelected(intI)) = False
Next intI
End With

End Sub

Private Sub Form_Current()

Dim rs As DAO.Recordset
Dim intI As Integer

' Clear all currently selected hobbies.
ClearHobbySelections

If Not Me.NewRecord Then

Set rs = CurrentDb.OpenRecordset( _
"SELECT HobbyID FROM tblFamilyMembersHobbies " & _
"WHERE MemberID=" & Me.MemberID)

' Select the hobbies currently on record for this MemberID.
With Me.lstHobbies
Do Until rs.EOF
For intI = 0 To (.ListCount - 1)
If .ItemData(intI) = CStr(rs!HobbyID) Then
.Selected(intI) = True
Exit For
End If
Next intI
rs.MoveNext
Loop
rs.Close
Set rs = Nothing
End With

End If

End Sub

Private Sub lstHobbies_AfterUpdate()

On Error GoTo Err_lstHobbies_AfterUpdate

Dim db As DAO.Database
Dim ws As DAO.Workspace
Dim strSQL As String
Dim blnInTransaction As Boolean
Dim varItem As Variant

' Make sure the current member record has been saved.
If Me.Dirty Then Me.Dirty = False

Set ws = Workspaces(0)
Set db = ws.Databases(0)

ws.BeginTrans
blnInTransaction = True

' Delete all hobbies now on record.
strSQL = "DELETE FROM tblFamilyMembersHobbies " & _
"WHERE Memberid = " & Me.MemberID

db.Execute strSQL, dbFailOnError

' Add each hobby selected in the list box.
With Me.lstHobbies
For Each varItem In .ItemsSelected
strSQL = _
"INSERT INTO tblFamilyMembersHobbies " & _
"(MemberID, HobbyID) VALUES (" & _
Me.MemberID & ", " & .ItemData(varItem) & ")"
db.Execute strSQL, dbFailOnError
Next varItem
End With

ws.CommitTrans
blnInTransaction = False

Exit_lstHobbies_AfterUpdate:
Set db = Nothing
Set ws = Nothing
Exit Sub

Err_lstHobbies_AfterUpdate:
MsgBox "Error " & Err.Number & ": " & Err.Description, _
vbExclamation, "Unable to Update"
If blnInTransaction Then
ws.Rollback
blnInTransaction = False
End If
Resume Exit_lstHobbies_AfterUpdate

End Sub

Private Sub lstHobbies_BeforeUpdate(Cancel As Integer)

Dim intI As Integer

' Don't allow hobbies to be updated before a MemberID has
' been generated.
If IsNull(Me.MemberID) Then
MsgBox "Please enter other information for this family " & _
"member before choosing hobbies.", , _
"Define Member First"
Cancel = True
Me.lstHobbies.Undo
' Clear the user's selection.
ClearHobbySelections
End If

End Sub
'----- end of code -----

As you see, there's a fair amount of code involved, because we're using
the list box to do something it wasn't built to do, but it works quite
nicely.
 
S

sparlaman

I can see by your answer that my question was not clear. I do understand the
principles of a relational database and I am not trying to store multiple
items in a single field.

I am trying to use form controls i.e. checkboxes and multiselect list boxes
to populate multiple records from a related table. So let me try to explain
again... I have a table "teachers_to_subjects" where each record contains one
teacher & one subject. It is in this manner that I am relating teachers to
subject in a many-to-many fashion. What I want is a form control that will
allow a user to select subjects per teacher thereby populating my
"teachers_to_subjects" table.

If you understand what I mean and can help me accomplish this. I'll greatly
appreciate it.

Thanks,
Sparlaman
 
D

Dirk Goldgar

sparlaman said:
I can see by your answer that my question was not clear. I do understand
the
principles of a relational database and I am not trying to store multiple
items in a single field.

I am trying to use form controls i.e. checkboxes and multiselect list
boxes
to populate multiple records from a related table. So let me try to
explain
again... I have a table "teachers_to_subjects" where each record contains
one
teacher & one subject. It is in this manner that I am relating teachers to
subject in a many-to-many fashion. What I want is a form control that will
allow a user to select subjects per teacher thereby populating my
"teachers_to_subjects" table.

If you understand what I mean and can help me accomplish this. I'll
greatly
appreciate it.


I don't think you read and understood my entire post. That's exactly what I
provided code to do.
 
P

Paul Shapiro

As Dirk said below, the most common way to enter 1:Many related data is with
a subform for the TeachersToSubjects, where each row in the subform is one
subject that's being taught by the current teacher on the main form. You
enter a new subject for the teacher by choosing the desired subject from the
combo box in the subform. No code is needed, just assigning the correct
properties to the subform control when it's dropped on the main form.

If you really want to use a multi-select list box instead of a subform,
Dirk's code is doing that. It's a lot of code because it's not the way
Access imagined you would use a list box.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top