Notice: This website is an unofficial Microsoft Knowledge Base (hereinafter KB) archive and is intended to provide a reliable access to deleted content from Microsoft KB. All KB articles are owned by Microsoft Corporation. Read full disclaimer for more details.

AutoNumber field is not reset after you compact an Access database


Moderate: Requires basic macro, coding, and interoperability skills.

This article applies to a Microsoft Access database (.mdb or .accdb) and to a Microsoft Access project (.adp).

↑ Back to the top


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.

↑ Back to the top


Cause

You have installed Microsoft Jet 4.0 Service Pack 4 (Msjet40.dll version 4.00.2927.4) or later.

↑ Back to the top


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:
  1. Click your table in the Database window.
  2. Press CTRL + C.
  3. Press CTRL + V.
  4. In the Paste Table As dialog box, click Structure Only, type the name tblNewTable, and then click
    OK.
  5. 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.
  6. In the Show Table dialog box, click the old table, click Add, and then click Close.
  7. 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.
  8. In the Append dialog box, click tblNewTable in the Table Name box, and then click OK.
  9. Add all the fields to the query design grid except the AutoNumber field.
  10. 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.
  11. 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

↑ Back to the top


Status

Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section.

↑ Back to the top


More Information

Steps to reproduce the problem

  1. Install Microsoft Jet 4.0 Service Pack 4 (SP4) or later.
    For more information about how to obtain the latest Microsoft Jet service pack, click the following article number to view the article in the Microsoft Knowledge Base:

    239114 How to obtain the latest service pack for the Microsoft Jet 4.0 Database Engine

  2. In Access 2003 or in Access 2002, create a new database.
  3. Create the following table:

    Table: tblExample
    ---------------------
    Field Name: ID
    Data Type: AutoNumber

    Field Name: MyText
    Data Type: Text

    Table Properties: tblExample
    ----------------------------
    PrimaryKey: ID
  4. Save the table as
    tblExample.
  5. On the View Menu, click Datasheet View.
  6. Add 10 records to the table.
  7. Delete the last three records that you added to the table.
  8. Close the table.
  9. On the Tools menu, point to Database Utilities, and then click Compact and Repair Database.
  10. Open the tblExample table.
  11. Add a new record to the table.

    Note that the AutoNumber is 11 rather than 8, as you would expect.
Note After you compact the project in a Microsoft Access project (.adp), you do see the number that you expect in the AutoNumber field when you add the record. However, when you save the record, the AutoNumber changes. In this example, you see 8 until the record is committed. Then, the number changes to 11. This happens because the AutoNumber is assigned on the server after the record is committed.
For more information, click the following article number to view the article in the Microsoft Knowledge Base:

202121 Cannot change default seed and increment value in UI

↑ Back to the top


Keywords: kbnofix, kbbug, kbswept, kboffice2003yes, kbbillprodsweep, kbsweptjet4sp, kbado, kbupdateissue, kb, kbprogramming, kboffice12yes, kbfreshness2006, kbsweptsoltax

↑ Back to the top

Article Info
Article ID : 287756
Revision : 3
Created on : 4/18/2018
Published on : 4/19/2018
Exists online : False
Views : 434