BUG: AutoNumber field is not reset after you compact an Access database (287756)
The information in this article applies to:
- Microsoft Office Access 2003
- Microsoft Access 2002
This article was previously published under Q287756 Moderate: Requires basic macro, coding, and interoperability
skills.
This article applies to a Microsoft Access database (.mdb) and to a
Microsoft Access project (.adp).
SYMPTOMS When you delete the last record or records in a table or in
a form that has an AutoNumber field, and then you compact the database, the
AutoNumber field does not start at the next higher number when you add new
records. CAUSE You have installed Microsoft Jet 4.0 Service Pack 4
(Msjet40.dll version 4.00.2927.4) or later. RESOLUTION 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.
- On the Edit Menu, click Copy.
- On the Edit Menu, click Paste.
- In the Paste Table As dialog box, click Structure Only, type the name tblNewTable, and then click
OK.
- On the View menu, point to Database Objects, and then click Queries.
- Click New.
- In the New Query dialog box, click Design View, and then click OK.
- In the Show Table dialog box, click the old table, click Add, and then click Close.
- On the Query menu, click Append Query.
- 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.
- On the Query menu, click Run 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
STATUSMicrosoft
has confirmed that this is a problem in the Microsoft products that are listed
at the beginning of this article.
Modification Type: | Minor | Last Reviewed: | 6/3/2004 |
---|
Keywords: | kbProgramming kbADO kbupdateissue kbbug kbnofix KB287756 kbAudDeveloper |
---|
|