Public Sub FillList(pTable As String)
'------------------------------------------------------------------
' Purpose: Delete/create temp table and fills it with unique values
' from comma delimited source strings
' Coded by: raskew
' Calls: Function StrCount
' Input: Call FillList("tblTemp")
' Returns: tblTemp filled with unique, sorted values from tblData
'------------------------------------------------------------------
Dim db As database
Dim rs As Recordset
Dim rs2 As Recordset
Dim strSQL As String
Dim strHold As String
Dim i As Integer
Dim n As Integer
On Error Resume Next
'Delete/create tblTemp
CurrentDb.Execute "DROP TABLE " & pTable & ";"
strSQL = "CREATE TABLE " & pTable & " " _
& "( Selection Text(20) Not Null );"
CurrentDb.Execute strSQL
CurrentDb.TableDefs.Refresh
Set db = CurrentDb
strSQL = "CREATE UNIQUE INDEX SelColor ON " & pTable & " ([Selection] ASC);"
db.Execute strSQL
Set rs = db.openrecordset("tblData")
Set rs2 = db.openrecordset(pTable)
Do While Not rs.EOF
strHold = Trim(rs!Selections)
i = StrCount(strHold, ",") + 1
For n = 1 To i
With rs2
.AddNew
If InStr(strHold, ",") > 0 Then
!Selection = Trim(Left(strHold, InStr(strHold, ",") - 1))
Else
!Selection = Trim(strHold)
End If
.Update
End With
strHold = Mid(strHold, InStr(strHold, ",") + 1)
Next n
rs.MoveNext
Loop
rs.Close
rs2.Close
db.Close
End Sub
Function StrCount(ByVal TheStr As String, theItem As Variant) As Integer
'------------------------------------------------------------------
' Purpose: Counts number of times item occurs in a string.
' Coded by: raskew
' Arguments: TheStr: The string to be searched.
' TheItem: The item to search for.
' Returns: The number of occurences as an integer.
'
' Note: To test: Type '? StrCount("The quick brown fox jumped over
' the lazy dog", "the") in the debug window.
' The function returns 2.
'------------------------------------------------------------------
Dim j As Integer
Dim placehold As Integer
Dim strHold As String
Dim itemHold As Variant
strHold = TheStr
itemHold = theItem
j = 0
If InStr(1, strHold, itemHold) > 0 Then
While InStr(1, strHold, itemHold) > 0
placehold = InStr(1, strHold, itemHold)
j = j + 1
strHold = Mid(strHold, placehold + Len(itemHold))
Wend
End If
StrCount = j
End Function