Slow DELETE or UPDATE against non-SQL linked server (309182)
The information in this article applies to:
- Microsoft SQL Server 2000 (all editions)
- Microsoft SQL Server 7.0
This article was previously published under Q309182 SYMPTOMS
UPDATE or DELETE statements that act against a remote table that resides on a non-SQL Server data source, may run much slower than an equivalent SELECT statement.
CAUSE
For linked server DELETEs or UPDATEs, SQL Server retrieves data from the table, performs any filtering that is necessary, and then performs the deletes or updates through the OLEDB rowset. This processing can result in a round-trip to the remote server for each row that is to be deleted or updated. The SET SHOWPLAN ON output may look something similar to this plan:
|--Remote Delete(SOURCE:(remserver), OBJECT:("".""."titles"))
|--Table Spool
|--Filter(WHERE:([remserver]...[titles].[royalty]=10))
|--Remote Scan(SOURCE:(remserver), OBJECT:("".""."titles"))
SQL Server 2000 adds the ability to send a DELETE or UPDATE to a linked server as a single SQL statement; however, this feature only covers linked servers to another SQL Server 2000 or SQL Server 7.0 instance. A plan that is taking advantage of this feature shows a Remote Query operator that sends a single DELETE SQL statement to the remote server instead of the Remote Delete operator seen previously. Following is a plan that is functionally equivalent to the preceding plan (but is only seen if the local server is a SQL Server 2000 server and [remserver] is a SQL Server 7.0 or SQL Server 2000 server):
|--Remote Query(SOURCE:(remserver), QUERY:(DELETE "".""."titles" FROM
"".""."titles" Tbl1001 WHERE Tbl1001."royalty"=(10)))
To take advantage of the new SQL Server 2000 behavior described above, the query must satisfy the following:
- The query must be a simple UPDATE/DELETE against a single remote
table.
- All selection criteria (in other words, predicates in the WHERE clause) must be remotable. For example, if the query includes the filter "WHERE col1 = 'abc'" and the remote server is not collation-compatible, SQL Server 2000 can't remote the UPDATE as a Remote Query because it can't trust the remote server to use the correct collation when deciding which rows to update.
- The local server must be SQL Server 2000, and the remote server must be either SQL Server 7.0 or 2000.
Modification Type: | Major | Last Reviewed: | 12/13/2005 |
---|
Keywords: | kbtshoot kbprb KB309182 kbAudITPRO kbAudDeveloper |
---|
|