ACC2000: Can't Use Upsized Append and Make-Table Queries in an Access Project

ID: Q229681


The information in this article applies to:

Advanced: Requires expert coding, interoperability, and multiuser skills.

This article applies only to a Microsoft Access project (.adp).


SYMPTOMS

When you try to run upsized make-table or append queries in a Microsoft Access project, you may receive the following error message:

Cannot run SELECT INTO in this database. The database owner must run sp_dboption to enable this option.
-or-
Cannot insert explicit value for identity column in table 'table name' when IDENTITY_INSERT is set to OFF.
You may also encounter the first error message when running an upsized update query.


CAUSE

When you create a new Microsoft Data Engine (MSDE) or SQL Server database, the select into/bulkcopy and IDENTITY_INSERT options are set to OFF.

Upsized Make-Table Queries

When you upsize a database that contains make-table queries, the queries migrate as stored procedures. These stored procedures use the SELECT INTO statement to create a new table and then add records to it. You must set the select into/bulkcopy option of the database to ON in any database that contains a stored procedure that uses the SELECT INTO statement.

Upsized Update and Append Queries

If you upsize a Microsoft Access table that contains a field of the AutoNumber data type, the field will be created on MSDE or SQL Server as an IDENTITY column. Unlike the AutoNumber data type, you cannot directly edit IDENTITY columns, nor explicitly insert data into an IDENTITY column while the IDENTITY_INSERT option for that table is set to OFF. To insert or update data in an IDENTITY column, you must set the IDENTITY_INSERT option to ON.


RESOLUTION

To set the select into/bulk copy option to ON for your database, create a stored procedure that uses the sp_dboption system stored procedure to toggle the setting. The following SQL sample modifies a database named MyDatabase so you can use SELECT INTO statements:


   CREATE PROCEDURE SetMyOptions
   AS
   EXEC sp_dboption 'MyDatabase','bulkcopy','ON' 
You can use the SET IDENTITY_INSERT statement to set the IDENTITY_INSERT option. SET IDENTITY_INSERT always references a table, and should be placed before the UPDATE or INSERT statement that modifies or inserts data into an IDENTITY column. The following example sets IDENTITY_INSERT for the NewEmployees table.

   SET IDENTITY_INSERT NewEmployees ON 


MORE INFORMATION

Steps to Reproduce Behavior

  1. Open the sample database Northwind.mdb.


  2. Create a new query in Design view, and close the Show Table dialog box without adding any tables or queries.


  3. On the View menu, click SQL View.


  4. Type the following SELECT statement into the SQL window. It will create a make-table query:


  5. 
       SELECT 
              Employees.EmployeeID, Employees.LastName, Employees.FirstName,
              Employees.Title, Employees.TitleOfCourtesy, Employees.BirthDate,
              Employees.HireDate, Employees.Address, Employees.City,
              Employees.Region, Employees.PostalCode, Employees.Country,
              Employees.HomePhone, Employees.Extension, Employees.Photo,
              Employees.Notes, Employees.ReportsTo
       INTO 
              NewEmployees
       FROM 
              Employees; 
  6. Save the query as qryMakeTable, and then close it.


  7. Create a second query in Design view, and close the Show Table dialog box without adding any tables or queries.


  8. On the View menu, click SQL View.


  9. Type the following INSERT INTO statement into the SQL window. It will create an append query:


  10. 
       INSERT INTO 
              NewEmployees (EmployeeID, LastName, FirstName, Title,
              TitleOfCourtesy, BirthDate, HireDate, Address, City, Region,
              PostalCode, Country, HomePhone, Extension, Photo, Notes,
              ReportsTo)
       SELECT 
              Employees.EmployeeID, Employees.LastName, Employees.FirstName,
              Employees.Title, Employees.TitleOfCourtesy, Employees.BirthDate,
              Employees.HireDate, Employees.Address, Employees.City,
              Employees.Region, Employees.PostalCode, Employees.Country,
              Employees.HomePhone, Employees.Extension, Employees.Photo,
              Employees.Notes, Employees.ReportsTo
       FROM 
              Employees; 
  11. Save the query as qryAppend, and then close it.


  12. On the Tools menu, point to Database Utilities, and then click Upsizing Wizard.


  13. Complete the steps in the Upsizing Wizard, using default selections, except where noted below:


  14. Create New Database: Yes
    Which tables do you want to export to SQL Server: Export all tables
    Add timestamp fields to tables: No, never
    Create a new Access client/server application: Yes
  15. Once the upsizing tool has completed its work, close the upsizing report.


  16. Try to run the qryMakeTable stored procedure, and note the error message.


  17. To set the select into/bulkcopy option to ON, create a stored procedure using the following SQL:


  18. 
       CREATE PROCEDURE SetMyOptions
       AS
       EXEC sp_dboption 'NorthwindSQL','bulkcopy','ON' 
  19. Save and run the stored procedure SetMyOptions.


  20. Run the stored procedure qryMakeTable again. Note that this time it succeeds.


  21. Try to run the qryAppend stored procedure and note the error message.


  22. To set IDENTITY INSERT to ON, add the following line of SQL to the qryAppend stored procedure directly after the keyword AS:
    
       SET IDENTITY_INSERT NewEmployees ON 
    When complete, your stored procedure should resemble the following text:


  23. 
       ALTER PROCEDURE qryAppend
       AS
       SET IDENTITY_INSERT NewEmployees ON
       INSERT INTO 
              NewEmployees (EmployeeID, LastName, FirstName, Title,
              TitleOfCourtesy, BirthDate, HireDate, Address, City, Region,
              PostalCode, Country, HomePhone, Extension, Photo, Notes,
              ReportsTo)
       SELECT 
              Employees.EmployeeID, Employees.LastName, Employees.FirstName,
              Employees.Title, Employees.TitleOfCourtesy, Employees.BirthDate,
              Employees.HireDate, Employees.Address, Employees.City, 
              Employees.Region, Employees.PostalCode, Employees.Country, 
              Employees.HomePhone, Employees.Extension, Employees.Photo, 
              Employees.Notes, Employees.ReportsTo
       FROM 
              Employees 
  24. Save the modified stored procedure, and then run it. Note that it succeeds.



REFERENCES

For more information about sp_dboption and IDENTITY INSERT, refer to SQL Server books online.

If you want to download the SQL Server Books Online, they are available at SQL Server 7.0 Books Online

Additional query words: prb


Keywords          : kbdta AccessCS 
Version           : WINDOWS:2000
Platform          : WINDOWS 
Issue type        : kbprb 

Last Reviewed: May 13, 1999