In order to parse comma-separated
Text fields, and to display the resulting text strings in multiple
Text fields, use one of the methods listed below:
Method 1
This method uses an expression in a query that includes three functions: the
Instr() function to search for the comma in the
Text field, and the
Left$() and
Right$() functions to extract the two parts of the
Text field.
To parse a
Text field that contains two words separated by a comma, follow these steps:
- Start Microsoft Access, and then open any existing database.
Create a table with the following structure:
Table: Parse2Words
------------------
Field Name: Empl
Data Type: Text
- View the Parse2Words table in Datasheet view, and then type the following three records in the Empl field:
Smith, John
Callahan, Laura
Fuller, Andrew
- Create the following query based on the Parse2Words table:
Query: QueryTest
------------------------------------------------------------------
Field: FirstName: Right$([Empl],Len([Empl]) - InStr(1,[Empl],",") -1)
Show: True
Field: LastName: Left$([Empl],InStr(1,[Empl],",") -1)
Show: True
NOTE: You can modify the QueryTest query to account for spaces between the two parts in the Empl field. For example, if the text in the Empl field is Smith,John without spaces, remove the "-1" from the FirstName field expression.
- Run the query. Note that the QueryTest query separates the text in the Empl field into the two fields below:
FirstName LastName
--------------------
John Smith
Laura Callahan
Andrew Fuller
Method 2
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
This method uses two user-defined functions: a function named CountCSWords() to count the number of comma-separated words in the
Text field, and a function named GetCSWord() to return the nth word in the
Text field.
To parse a
Text field that contains more than two words separated by commas, follow these steps:
- Start Microsoft Access, and then open any database.
- Create a table with the following structure:
Table: ParseWords
--------------------
Field Name: Location
Data Type: Text
- View the ParseWords table in Datasheet view, and then type the following three records in the Location field:
Toronto, Ontario, Canada
Boston, Massachusetts, USA
Vancouver, British Columbia, Canada
- Create a module, and then type Option Explicit in the Declarations section if it is not already there.
- Type the following procedures:
Function CountCSWords(ByVal S) As Integer
' Counts the words in a string that are separated by commas.
Dim WC As Integer, Pos As Integer
If VarType(S) <> 8 Or Len(S) = 0 Then
CountCSWords = 0
Exit Function
End If
WC = 1
Pos = InStr(S, ",")
Do While Pos > 0
WC = WC + 1
Pos = InStr(Pos + 1, S, ",")
Loop
CountCSWords = WC
End Function
Function GetCSWord(ByVal S, Indx As Integer)
' Returns the nth word in a specific field.
Dim WC As Integer, Count As Integer, SPos As Integer, EPos As Integer
WC = CountCSWords(S)
If Indx < 1 Or Indx > WC Then
GetCSWord = Null
Exit Function
End If
Count = 1
SPos = 1
For Count = 2 To Indx
SPos = InStr(SPos, S, ",") + 1
Next Count
EPos = InStr(SPos, S, ",") - 1
If EPos <= 0 Then EPos = Len(S)
GetCSWord = Trim(Mid(S, SPos, EPos - SPos + 1))
End Function
- Compile the module, save it as basParse, and then close it.
- Create the following query based on the ParseWords table:
Query: QueryTest2
---------------------------------------
Field: City: GetCSWord([Location],1)
Show: True
Field: Region: GetCSWord([Location],2)
Show: True
Field: Country: GetCSWord([Location],3)
Show: True
- Run the query. Note that the QueryTest2 query separates the text in the Location field into the three fields below:
City Region Country
--------------------------------------
Toronto Ontario Canada
Boston Massachusetts USA
Vancouver British Columbia Canada