ACC2000: New SQL Records Appear Deleted Until Recordset Reopened

This article has been archived. It is offered "as is" and will no longer be updated.
Advanced: Requires expert coding, interoperability, and multiuser skills.

This article applies only to a Microsoft Access database (.mdb).

Symptoms
When you add a record to an SQL table using Visual Basic forApplications, if the table's unique index field has a default value, andyou do not assign a value to that field, the new record appears deleteduntil you reopen the SQL table. If you try to obtain a value from the newrecord, you receive the following error message:
Run-time error '3167'

Record is deleted.
Resolution
To resolve this behavior, when you open the SQL table by using Visual Basic code, include the dbSeeChanges option, as in the following example:
Set rs = db.OpenRecordset("TestTable", dbOpenDynaset, dbSeeChanges)				
The dbSeeChanges option ensures that any newly added records that contain a default value in the unique index field are available in the current recordset.
More information
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.

Steps to Reproduce Behavior

NOTE: The sample code in this article uses Microsoft Data Access Objects. For this code to run properly, you must reference the Microsoft DAO 3.6 Object Library. To do so, click References on the Tools menu in the Visual Basic Editor, and make sure that the Microsoft DAO 3.6 Object Library check box is selected.

  1. Create a module and type the following line in the Declarations section if it is not already there:
    Option Explicit
  2. Type the following procedure:
    Function TestSQLData()   Dim db As DAO.Database, rs As DAO.Recordset   Dim idx, td   Dim cmd As String   ' Delete TestTable if it exists on the SQL server.      'Insert your database name, user ID, password (if any), and dsn   'to point to an ODBC data source.   Set db = OpenDatabase("<MyDatabase>", False, False, _   "ODBC, Database = <MyDatabase>, UID = <userid>, PWD = <password>, dsn = <MyDSN>")   cmd = "if exists (select * from sysobjects where" _      & " id = object_id('dbo.TestTable'))"   cmd = cmd & " drop table TestTable"   db.Execute cmd, dbSQLPassThrough   ' Create TestTable with one field on SQL server.   Set td = db.CreateTableDef("TestTable")   td.Fields.Append td.CreateField("Int", dbInteger)   td.Fields.Append td.CreateField("String", dbText, 50)   db.TableDefs.Append td   Set idx = td.CreateIndex("MyIdx")   idx.Unique = True   idx.Fields.Append idx.CreateField("Int")   td.Indexes.Append idx   cmd = "create Default TestDef3 as 100"   db.Execute cmd, dbSQLPassThrough   cmd = "sp_bindefault TestDef3, 'TestTable.Int'"   db.Execute cmd, dbSQLPassThrough   ' Open table, add a record, and then obtain values.   Set rs = db.OpenRecordset("TestTable")   rs.AddNew   rs!String = "Trial"   rs.Update   Debug.Print "RecordCount = " & rs.RecordCount   rs.MoveFirst   Debug.Print "String is " & rs("String")   Debug.Print "Int is " & rs("Int")   rs.CloseEnd Function					
  3. To test this function, type the following line in the Immediate window, and then press ENTER:
    ? TestSQLData()
    Note that the run-time error 3167 occurs.
prb run time error 3167
Properties

Article ID: 208799 - Last Review: 01/14/2015 02:50:00 - Revision: 4.0

  • Microsoft Access 2000 Standard Edition
  • kbnosurvey kbarchive kberrmsg kbprb kbusage KB208799
Feedback