PRB: Stored Procedure Calls May Result in Attentions Being Seen on SQL Server

ID: Q240882


The information in this article applies to:
  • Microsoft ODBC Driver for SQL Server, versions 3.5, 3.6, 3.7
  • Microsoft SQL Server versions 6.5, 7.0


SYMPTOMS

A SQL Server trace may reveal excessive Attentions and Rollbacks due to client disconnects. However, the client does not receive an error message.


CAUSE

SQL Server stored procedures, which are not expected to return a resultset, may return a large volume of informational data (DONE_IN_PROC messages) that are occasionally sufficient to overrun a packet buffer.

When this happens, the SQL Server driver issues a disconnect. The most visible evidence of this disconnect is an Attention showing up in a SQL Server trace.


RESOLUTION

Modify the SQL Server stored procedure so the first instruction is SET NOCOUNT ON. This prevents the majority of DONE_IN_PROC messages from being sent back to the client and avoids the packet buffer overflow.


STATUS

This behavior is by design.


MORE INFORMATION

When SET NOCOUNT is ON, the count (indicating the number of rows affected by a Transact-SQL statement) is not returned. When SET NOCOUNT is OFF, the count is returned.

The @@ROWCOUNT function is updated even when SET NOCOUNT is ON.

SET NOCOUNT ON eliminates the sending of DONE_IN_PROC messages to the client for each statement in a stored procedure. When using the utilities provided with Microsoft® SQL Server™ to execute queries, the results prevent "nn rows affected" from being displayed at the end of Transact-SQL statements such as SELECT, INSERT, UPDATE, and DELETE.

For stored procedures that contain several statements that do not return much actual data this can provide a significant performance boost because network traffic can be reduced. The setting of SET NOCOUNT is set at execute or run-time and not at parse time.

Examples

This example (when executed in the osql utility or SQL Server Query Analyzer) prevents the message (about the number of rows affected) from being displayed:


USE pubs

GO

-- Display the count message.

SELECT au_lname 

FROM authors

GO

USE pubs

GO

-- SET NOCOUNT to ON and no longer display the count message.

SET NOCOUNT ON

GO

SELECT au_lname 

FROM authors

GO

-- Reset SET NOCOUNT to OFF.

SET NOCOUNT OFF

GO 

Additional query words:

Keywords : kbODBC odbcSQL kbSQLServ650 kbSQLServ700 kbGrpMDAC kbGrpODBC
Version : WINDOWS:3.5,3.6,3.7; winnt:6.5,7.0
Platform : WINDOWS winnt
Issue type : kbprb


Last Reviewed: October 8, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.