Module: MultiValueFields in Category Access/Jet Databases : Fields from Total Visual SourceBook

Add, edit, delete and retrieve values from MultiValue fields by updating records in Access ACCDB database tables using DAO with VBA and VB6.

Procedure Name Type Description
(Declarations) Declarations Declarations and private variables for the modMultiValueFields module.
IsFieldMultiValue Procedure Check if the specified field in a table in the specified database is a multivalue field.
GetMultiValueFieldData Procedure Create an array with a multivalue field's list of values.
GetMultiValueTableData Procedure Get all the values from the specified multivalue field from a filtered table.
AddValueToMultiValueField Procedure Add one value to a multivalue field. The record must already be in add or edit mode.
AddValuesToMultiValueField Procedure Add multiple values to a multivalue field. The record must already be in add or edit mode.
AddValueToMultiValueRecords Procedure Add one value to a multivalue field for every record that matches the filter.
AddValuesToMultiValueRecords Procedure Add multiple values to a multivalue field for every record that matches the filter.
DeleteMultiValue Procedure Delete values from a multivalue field.
' Example of modMultiValueFields
'
' To use this example, create a new module and paste this code into it.
' Then run the procedure by putting the cursor in the procedure and pressing:
'    F5 to run it, or
'    F8 to step through it line-by-line (see the Debug menu for more options)

' This example assumes that this sample database exists, and contains the objects listed in the constants below.
Private Const mcstrSamplePath As String = "C:\Total Visual SourceBook 2013\Samples\"
Private Const mcstrSampleDB As String = "Sample.accdb"
Private Const mcstrTableName As String = "Customers-Complex"
Private Const mcstrMultiValueField As String = "Languages"
Private Const mcstrIDField As String = "CustomerID"
Private Const mcstrFilter As String = "CustomerID = 'NWIND'"
Private Const mcstrNewValue1 As String = "NewValue1"
Private Const mcstrNewValue2 As String = "NewValue2"

Private Sub Example_modMultiValueFields()
  ' Comments: Examples of using the modMultiValueFields module to manage multivalue fields in Microsoft Access ACCDB databases in VBA and VB6.

  Dim dbs As DAO.Database
  Dim rst As DAO.Recordset
  Dim fld As DAO.Field
  Dim avarValues() As Variant
  Dim intCount As Integer
  Dim intCounter As Integer

  ' Initialize database, table, and field variables
  Set dbs = OpenDatabase(mcstrSamplePath & mcstrSampleDB, False, False)
  Set rst = dbs.OpenRecordset(mcstrTableName, dbOpenDynaset, dbSeeChanges)
  Set fld = rst.Fields(mcstrMultiValueField)

  ' See if a field is a MultiValue data type
  If IsFieldMultiValue(dbs, mcstrTableName, mcstrMultiValueField) Then
    Debug.Print "Field [" & mcstrMultiValueField & "] is a MultiValue field."
  Else
    Debug.Print "Field [" & mcstrMultiValueField & "] is NOT a MultiValue field."
  End If

  If IsFieldMultiValue(dbs, mcstrTableName, mcstrIDField) Then
    Debug.Print "Field [" & mcstrIDField & "] is a MultiValue field."
  Else
    Debug.Print "Field [" & mcstrIDField & "] is NOT a MultiValue field."
  End If

  rst.MoveFirst
  Do Until rst.EOF
    ' Create an array with the current record's multivalue field's list of values
    intCount = GetMultiValueFieldData(fld, avarValues)
    Debug.Print "GetMultiValueFieldData returned " & intCount & " values where " & mcstrIDField & "=" & rst.Fields(mcstrIDField)
    For intCounter = 1 To intCount
      Debug.Print "    - " & avarValues(intCounter)
    Next intCounter
    rst.MoveNext
  Loop

  ' Get all the values from the specified multivalue field from a filtered table
  intCount = GetMultiValueTableData(dbs, mcstrTableName, mcstrMultiValueField, mcstrFilter, avarValues)
  Debug.Print "GetMultiValueTableData returned " & intCount & " values where " & mcstrFilter & ": "
  For intCounter = 1 To intCount
    Debug.Print "    - " & avarValues(intCounter)
  Next intCounter

  rst.MoveFirst
  rst.Edit
  ' Add one value to a MultiValue field.  The record needs to be in add or edit mode for this.
  If AddValueToMultiValueField(mcstrNewValue1, fld) Then
    Debug.Print mcstrNewValue1 & " added to the first record."
  Else
    Debug.Print mcstrNewValue1 & " could not be added to the first record."
  End If
  rst.Update

  ' Remove the values from the multivalue fields
  DeleteTestValues dbs

  ' Add values from an array to a MultiValue field
  Erase avarValues
  ReDim avarValues(0 To 1)
  avarValues(0) = mcstrNewValue1
  avarValues(1) = mcstrNewValue2
  rst.MoveFirst
  rst.Edit
  ' The record must already be in add or edit mode.
  If AddValuesToMultiValueField(avarValues, fld) Then
    Debug.Print "2 values added to the first record."
  Else
    Debug.Print "Values could not be added to the first record."
  End If
  rst.Update

  ' Remove the values from the multivalue fields
  DeleteTestValues dbs

  ' Add one value to a MultiValue field for every record that matches the filter
  If AddValueToMultiValueRecords(mcstrNewValue1, dbs, mcstrTableName, mcstrMultiValueField, mcstrFilter) Then
    Debug.Print mcstrNewValue1 & " added where " & mcstrFilter & "."
  Else
    Debug.Print mcstrNewValue1 & " could not be added where " & mcstrFilter & "."
  End If

  ' Remove the values from the multivalue fields
  DeleteTestValues dbs

  ' Add multiple values to a MultiValue field for every record that matches the filter
  If AddValuesToMultiValueRecords(avarValues, dbs, mcstrTableName, mcstrMultiValueField, mcstrFilter) Then
    Debug.Print "2 values added where " & mcstrFilter & "."
  Else
    Debug.Print "Values could not be added where " & mcstrFilter & "."
  End If

  ' Remove the values from the multivalue fields
  DeleteTestValues dbs

  ' Clean up
  Set fld = Nothing

  rst.Close
  Set rst = Nothing

  dbs.Close
  Set dbs = Nothing

End Sub

Private Sub DeleteTestValues(dbs As DAO.Database)
  ' Comments: Delete values from MultiValue field (used to reset the changes) in VBA and VB6.
  ' Params  : dbs       Database handle

  If DeleteMultiValue(dbs, mcstrTableName, mcstrMultiValueField, , mcstrNewValue1) Then
    Debug.Print mcstrNewValue1 & " deleted."
  Else
    Debug.Print mcstrNewValue1 & " could not be deleted."
  End If

  If DeleteMultiValue(dbs, mcstrTableName, mcstrMultiValueField, , mcstrNewValue2) Then
    Debug.Print mcstrNewValue2 & " deleted."
  Else
    Debug.Print mcstrNewValue2 & " could not be deleted."
  End If

End Sub

Total Visual SourceBook The source code in Total Visual Sourcebook includes modules and classes for Microsoft Access, Visual Basic 6 (VB6), and Visual Basic for Applications (VBA) developers. Easily add this professionally written, tested, and documented royalty-free code into your applications to simplify your application development efforts.

Total Visual SourceBook is written for the needs of a developer using a source code library covering the many challenges you face. Countless developers over the years have told us they learned some or much of their development skills and tricks from our code. You can too!

Additional Resources

Total Visual SourceBook CD and Printed Manual

Microsoft Access/ Office 2016, 2013, 2010, and 2007 Version
is Shipping!

New features in Total Visual SourceBook for Access, Office and VB6

Supports Access/Office 2016, 2013, 2010 and 2007, and Visual Basic 6.0!


View all FMS products for Microsoft Access All Our Microsoft Access Products

Reviews

Reader Choice Award for MS Access Source Code Library
Reader Choice

"The code is exactly how I would like to write code and the algorithms used are very efficient and well-documented."

Van T. Dinh, Microsoft MVP

SourceBook Info

Additional Info

Question

 

 

Free Product Catalog from FMS