ACC: Use Append Query to Set Initial Value of AutoNumber Field
ID: Q94821
|
The information in this article applies to:
-
Microsoft Access versions 1.0, 1.1, 2.0, 7.0, 97
SUMMARY
Moderate: Requires basic macro, coding, and interoperability skills.
By using an append query, you can change the starting value of an
AutoNumber field in a table (or Counter field in Microsoft Access 1.x and
2.0) to a number other than 1.
MORE INFORMATION
By design, Microsoft Access always numbers AutoNumber fields beginning
with the number 1. You cannot edit an AutoNumber field or change its
starting value.
However, you can force Microsoft Access to number an AutoNumber field with
a number you choose by following these general steps:
- Copy the design of the original table in which you want to set the
starting AutoNumber value to a new table.
- Change the AutoNumber field in the new table to a Number field with a
FieldSize property of Long Integer.
- Add a record to the new table, and set the Number field to a value that
is one less than the starting number you want for your original table.
For example, if you want the AutoNumber field to start at 100, type 99
in the Number field of the new table.
- Use an append query to add this new record to your original table.
This action forces Microsoft Access to number any new AutoNumber
fields with your number plus 1.
NOTE: Do not compact the database before you add a new record to the
original table. If you do, Microsoft Access will reset the AutoNumber
field value to the number 1.
The following example uses the sample database Northwind.mdb (or NWIND.MDB
in version 1.x or 2.0) to set a new starting value for an AutoNumber field
in the Employees table:
CAUTION: Following the steps in this example will modify the sample
database Northwind.mdb(or NWIND.MDB in version 1.x or 2.0). You may
want to back up the Northwind.mdb (or NWIND.MDB) file and perform these
steps on a copy of the database.
- Open the sample database Northwind.mdb (or NWIND.MDB in version 1.x or
2.0).
- Select the Employees table, and on the Edit menu, click Copy.
- On the Edit menu, click Paste.
- In the Paste Table As dialog box, type EmployeesTemp in the Table Name
box, and then click the Structure Only option. Click OK.
- Open the EmployeesTemp table in Design view.
- Change the data type of the EmployeeID field to Number, and set its
FieldSize property to Long Integer.
NOTE: In Microsoft Access 1.x and 2.0, the Employee ID field contains
a space.
- Save the EmployeesTemp table and close it.
- Open the EmployeesTemp table in Datasheet view and add the following
new record:
Employee ID: 99
Last Name: <Type your last name>
First Name: <Type your first name>
Birth Date: <Type your birth date>
- Create a new query in Design view based on the EmployeesTemp table.
- Add all fields from the table to the QBE grid.
- On the Query menu, click Append Query (or Append in Microsoft Access
1.x, 2.0, and 7.0).
- Select Employees in the Append To Table Name box, and then click OK.
- On the Query menu, click Run. Microsoft Access displays the following
message:
In Microsoft Access 7.0 and 97:
You are about to append 1 row(s).
In Microsoft Access 1.x and 2.0:
1 Row(s) will be appended.
Click Yes (or OK) to append the record to the Employees table.
- Close the query and do not save it.
- Delete the EmployeesTemp table, and then delete the newly appended
record from the Employees table.
- Open the Employees table in Datasheet view and add a new record. Note
that the Employee ID field starts numbering at 100.
REFERENCES
For more information about AutoNumber fields, type "starting value
AutoNumber" in the Office Assistant, click Search, and then click to view
"Change the starting value of an incrementing AutoNumber field."
Additional query words:
appending starting initial
Keywords : kbusage QryMktbl
Version : 1.0 1.1 2.0 7.0 97
Platform : WINDOWS
Issue type : kbinfo
|