Error messages when you perform an UPDATE, INSERT, or DELETE Transact-SQL statement on a remote table by using the OpenQuery function: "7357" and "7320" (270119)
The information in this article applies to:
- Microsoft SQL Server 7.0
- Microsoft SQL Server 2000 (all editions)
- Microsoft SQL Server 2005 Standard Edition
- Microsoft SQL Server 2005 Developer Edition
- Microsoft SQL Server 2005 Enterprise Edition
- Microsoft SQL Server 2005 Express Edition
- Microsoft SQL Server 2005 Workgroup
This article was previously published under Q270119 SYMPTOMS Distributed queries that use the OpenQuery function to update, delete, or insert data in the following way
exec sp_dropserver 'linked1', 'droplogins'
exec sp_addlinkedserver 'linked1', 'SQL Server'
exec sp_setnetname 'linked1', '<servername>'
exec sp_addlinkedsrvlogin 'linked1', 'false', null, '<login name>', '<password>'
SET ANSI_NULLS ON
go
SET ANSI_WARNINGS ON
go
select * from openquery (linked1, 'update testlinked set ssn=ssn+1')
select * from openquery (linked1, 'insert into testlinked (ssn) values (1000)')
select * from openquery (linked1, 'delete from testlinked where ssn=1')
may generate the following error messages:
Server: Msg 7357, Level 16, State 2, Line 1 Could not process object 'update
testlinked set ssn=ssn'. The OLE DB provider 'SQLOLEDB' indicates that the
object has no columns.
Server: Msg 7357, Level 16, State 2, Line 1
[Microsoft][ODBC SQL Server Driver][SQL Server]Could not process object 'update
testlinked set ssn=ssn'. The OLE DB provider 'MSDASQL' indicates that the
object has no columns. The actual text message of the error may vary
depending on the OLE DB provider and the operation (UPDATE, INSERT, or DELETE)
being performed, but the error number is always 7357. If you are using Microsoft SQL Server 2005, you receive the following error message:
Server: Msg 7357, Level 16, State 2, Line 1 Cannot process the object "update
testlinked set ssn=ssn". The OLE DB provider "SQLOLEDB" for linked server "ServerName" indicates that either the object has no columns or the current user does not have permissions on that object. CAUSEOpenQuery requires a result set to be returned, but UPDATE, DELETE, and
INSERT statements that are used with OpenQuery do not return a result set. WORKAROUND You can work around this problem in the following ways:
- Use four-part names
(linked_server_name.catalog.schema.object_name) to do insert, update, or delete
operations.
- As documented in SQL Server Books Online, reference the OpenQuery function as the target table of an INSERT, UPDATE, or DELETE
statement, subject to the capabilities of the OLE DB provider. The following
queries demonstrate proper usage with the SQL Server OLE DB provider:
update openquery(linked1, 'select ssn from testlinked where ssn=2')
set ssn=ssn + 1
insert openquery(linked1, 'select ssn from testlinked where 1=0') values (1000)
delete openquery(linked1, 'select ssn from testlinked where ssn>100')
Note In the INSERT statement, a where 1=0 predicate is used to avoid
retrieving data from the remote server, which can result in slower performance.
Also, UPDATE and DELETE operations have special index requirements; see the
"More Information" section for details.
Modification Type: | Major | Last Reviewed: | 12/21/2005 |
---|
Keywords: | kbprb KB270119 |
---|
|