Creating the PostalCodeExample Table Used in This Article
-
Start Microsoft Access, and then create a new blank database.
-
In the Database dialog box, double-click Create table in Design view, and then create the following table:
Table: PostalCodeExample
Field Name: PCode
Data Type: Text
-
Close the table, click Yes to save the table, and then in the Save As dialog box, enter PostalCodeExample. Do not create a primary key.
Restoring Leading Zeros That Are Missing
Store ZIP codes in a Text field in your table rather than in a Number field. Microsoft Access follows standard mathematical conventions when
storing numeric data, so if you enter a ZIP code that contains leading
zeros in a Number field, Microsoft Access removes the leading zeros when
you save the data. For example, if you enter 01002 in a Number field,
Microsoft Access stores the number as 1002.
To restore leading zeros to ZIP codes that have been
stored in a Number field, follow these steps:
- In the Database dialog box, under Objects, click Tables.
- Click PostalCodeExample table, and then click Open. Enter the following five- and nine-digit ZIP code records:
00345
023456789
- On the View menu, click Design View.
- Change the data type of the PCode field to Number, and set the FieldSize property to Long Integer.
- Save the table, and then on the View menu click Datasheet View. Note that the leading zeros have been removed.
- On the View menu, click Design View and return the data type of the PCode field to Text so that it can store the restored leading zeros in your ZIP codes. Save the table.
- Create the following update query based on the PostalCodeExample table.
Query Name: RestoreLeadingZeros
Query Type: Update Query
Field: PCode
Table: PostalCodeExample
Update To: IIf(Len([PCode])<6, Format([PCode],"00000"), _
�����Format([PCode],"000000000"))
- Run the query and confirm the update when prompted. Open the PostalCodeExample table. Note that the leading zeros have been restored.
Saving Formatted ZIP Codes
The Input Mask Wizard helps you to create an input mask for ZIP codes that
stores a hyphen after the fifth digit as a literal character. However, when
the hyphen is stored as a literal character, it is saved in all ZIP codes,
whether it is a five-digit or nine-digit code. The U.S. Postal Service will
accept ZIP codes with trailing hyphens, but you may want to avoid trailing
hyphens for aesthetic reasons.
If you omit the input mask, you can avoid trailing hyphens in your 5-digit
ZIP codes. Then you can either manually include the hyphen when you enter
nine-digit (ZIP+4) ZIP codes, or you can use a form to programmatically
insert the hyphen after a nine-digit (ZIP+4) ZIP code has been entered. In
either case, you also gain the ability to enter foreign postal codes in
your table.
To create a form that will programmatically insert a
hyphen when a nine-digit (ZIP+4) ZIP Code is entered, follow these steps:
- Create a new form based on the PostalCodeExample table using the AutoForm: Columnar Wizard.
- Save the form as frmFormatZIP, and then on the View menu click Design View.
- On the View menu, click Code.
- Type the following line in the Declarations section of the form's class module sheet:
- Type the following procedures:
Private Sub PCode_AfterUpdate()
If IsEmpty(mvarZip) Then Exit Sub
If Len(mvarZip) = 6 Then
Screen.ActiveControl = Left(mvarZip, Len(mvarZip)-1)
Else
Screen.ActiveControl = Format(mvarZip, "@@@@@-@@@@")
End If
mvarZip = Empty
End Sub
Private Sub PCode_BeforeUpdate(Cancel As Integer)
Dim ctlZip As Control
Dim strTitle As String
Dim strMsg As String
Const cYesNoButtons = 4
Const cNoChosen = 7
mvarZip = Empty
Set ctlZip = Screen.ActiveControl
If ctlZip Like "#####-####" Or ctlZip Like "#####" Then
Exit Sub
ElseIf ctlZip Like "#########" Or ctlZip Like "#####-" Then
mvarZip = ctlZip
Else
strTitle = "Not a ZIP Code."
strMsg = "Save as entered?"
If MsgBox(strMsg, cYesNoButtons, strTitle) = cNoChosen Then
Cancel = True
End If
End If
End Sub
- On the File menu, click Close and Return to Microsoft Access.
- On the View menu, click Form View, and then add the following new records:
01234
987651011
WA1 1DP
1010
NOTE: When you enter WA1 1DP and 1010, and are prompted to save the ZIP codes as entered, click Yes. - Save and close the form, and then open the PostalCodeExample table. Note that the five-digit ZIP code you entered does not contain a hyphen, the nine-digit ZIP code you entered does contain a hyphen, and the other two records you entered are stored as entered.
Removing Trailing Hyphens from Existing ZIP Codes
You can use an update query to remove trailing hyphens from existing ZIP
codes. Follow these steps to remove the trailing hyphens:
- Open the PostalCodeExample table and enter the following records:
12345-
987654321
12345-6789
- Create the following update query based on the PostalCodeExample table:
Query Name: RemoveTrailingHyphens
Query Type: Update Query
Field: [PCode] Like "#####-"
Criteria: True
Field: PCode
Table: PostalCodeExample
Update To: Left([PCode], Len([PCode])-1)
- Run the query and confirm the update when prompted.
- Open the PostalCodeExample table. Note that the trailing hyphen after "12345" has been removed.
Inserting hyphens in Existing Nine-Digit (ZIP+4) ZIP Codes
You can use an update query to insert missing hyphens in nine-digit ZIP
codes. Follow these steps to insert a hyphen in nine-digit ZIP codes:
- Open the PostalCodeExample table and enter the following records:
12345
987654321
12345-6789
- Create the following update query based on the PostalCodeExample table:
Query Name: InsertHyphens
Query Type: Update Query
Field: [PCode] Like "#########"
Criteria: True
Field: PCode
Update To: Format([PCode],"@@@@@-@@@@")
- Run the query and confirm the update when prompted.
- Open the PostalCodeExample table. Note that the nine-digit (ZIP+4) ZIP codes all contain hyphens after the fifth digit.
Formatting ZIP Codes for Use in Reports or Other Applications
You can use your ZIP codes in a Microsoft Access report or in another
application (such as Microsoft Word) without modification if they already
are saved in the desired format. Earlier sections in this article
demonstrate how to change the way your existing ZIP code formats are stored
in the table. However, if you want to format ZIP codes without changing the
way they are stored, you can follow these steps to temporarily create the
ZIP code format you want to use.
- Open the PostalCodeExample table, and then enter the following records:
54321
12345-
987654321
12345-6789
- Create the following query based on the PostalCodeExample table.
NOTE: In this example, the underscore (_) at the end of the Field line is used as a line-continuation character. Remove the underscore from the end of the line when you create this query.
Query Name: FormatZIPCodes
Query Type: Select Query
Field: Postal Code: IIf([PCode] Like "#####-", Left([PCode], _
�����Len([PCode])-1), IIf([PCode] Like _
�����"#########",Format([PCode], "@@@@@-@@@@"), _
�����[PCode]))
- Run the query. Note that trailing hyphens are not displayed and that a hyphen appears after the fifth digit in nine-digit ZIP codes. You can use this query instead of your table when you create your report or share the data with another application. This select query displays formatted ZIP codes but it does not alter your table's existing ZIP code data.