Module Data Storage

C

CorporateQAinTX

I'm trying to create a multiselect listbox and be able to store what data is
selected. I'm using the example almost directly from the Help file:

Sub AllSelectedData()
Dim frm As Form, ctl As Control
Dim varItm As Variant, intI As Integer

Set frm = Forms!Form1
Set ctl = frm!lstProd
For Each varItm In ctl.ItemsSelected
For intI = 0 To ctl.ColumnCount - 1
Debug.Print ctl.Column(intI, varItm)
Next intI
Debug.Print
Next varItm
End Sub

It's just being saved as Module1.

When I call the function in the immediate window, it shows me what I've got
selected. But how do I store this information and pull it back up when I open
the record again? Also, would I be able to use this information for searching
the table using a query?

TIA,

Garrett
 
S

Scott Lichtenberg

Garrett

The link below might help you. However, please note that the multi-select
listbox is not designed to store data. You can't bind it to a field in a
table or query. If you are going to use it, however, you would need code in
the OnCurrent event of the form to load the values into the listbox and in
the BeforeUpdate event to write back any changes. The link has some sample
functions.


http://support.microsoft.com/default.aspx?scid=kb;en-us;210203

Hope this helps.

========
 
D

Dirk Goldgar

Scott Lichtenberg said:
Garrett

The link below might help you. However, please note that the multi-select
listbox is not designed to store data. You can't bind it to a field in a
table or query. If you are going to use it, however, you would need code
in the OnCurrent event of the form to load the values into the listbox and
in the BeforeUpdate event to write back any changes. The link has some
sample functions.


http://support.microsoft.com/default.aspx?scid=kb;en-us;210203


Gack! They're providing code to store multiple selections in a single
field? Arrgh!

Garret, here's an example of how to use a multiselect combo box to load and
store selections from/to a related table, one selection per record.

*** 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.
 

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