Use one of the following two methods to work around this behavior.
Method 1
Create a new table and append the existing records to the new table. New records that are added to this table will start with an AutoNumber value of one unless you set the increment value programmatically.
Note If you no longer need your records, you can also reset the AutoNumber field by deleting all the records from the table, and then compacting the database. However, if you use this method, you cannot get the deleted records back.
To create a new table and append the existing records to the new table in a Microsoft Access database (.mdb), follow these steps:
- Click your table in the Database window.
- Press CTRL + C.
- Press CTRL + V.
- In the Paste Table As dialog box, click Structure Only, type the name tblNewTable, and then click
OK. - In Microsoft Office Access 2003 or in Microsoft Access 2002, point to Database Objects on the View menu, click Queries, and then double-click Create query in Design view.
In Microsoft Office Access 2007, click the Create tab, and then click Query Design in the Other group. - In the Show Table dialog box, click the old table, click Add, and then click Close.
- In Access 2003 or in Access 2002, click Append Query on the Query menu.
In Access 2007, click Appendin the Query Type group on the Design tab. - In the Append dialog box, click tblNewTable in the Table Name box, and then click OK.
- Add all the fields to the query design grid except the AutoNumber field.
- In Access 2003 or in Access 2002, on the Query menu, click Run to append the records to your new table.
In Access 2007, click Run in the Results group on the Design tab to append the records to your new table. - Open the tblNewTable table, and then add a record.
Note that the AutoNumber is next higher number.
Method 2
You can use the following function in a Microsoft Access database (.mdb) to programmatically reset the seed value of your AutoNumber field. You can add the function to a module, and then run it in the Debug window. Or, you can call the function from a command button or from a macro.
Note For this code to run correctly, you must reference both the Microsoft ActiveX Data Objects 2.x and the Microsoft ADO Ext 2.x for DDL and Security Libraries (where 2.x is 2.1 or later.) To do so, click
References on the
Tools menu in the Visual Basic Editor. Make sure that the
Microsoft ActiveX Data Objects 2.x and the
Microsoft ADO Ext 2.x for DDL and Security Libraries check boxes are selected.
Function ChangeSeed(strTbl As String, strCol As String, lngSeed As Long) As Boolean
'You must pass the following variables to this function.
'strTbl = Table containing autonumber field
'strCol = Name of the autonumber field
'lngSeed = Long integer value you want to use for next AutoNumber.
Dim cnn As ADODB.Connection
Dim cat As New ADOX.Catalog
Dim col As ADOX.Column
'Set connection and catalog to current database.
Set cnn = CurrentProject.Connection
cat.ActiveConnection = cnn
Set col = cat.Tables(strTbl).Columns(strCol)
col.Properties("Seed") = lngSeed
cat.Tables(strTbl).Columns.Refresh
If col.Properties("seed") = lngSeed Then
ChangeSeed = True
Else
ChangeSeed = False
End If
Set col = Nothing
Set cat = Nothing
Set cnn = Nothing
End Function