|
Posted by Erland Sommarskog on 09/09/06 12:58
(billmiami2@netscape.net) writes:
> I'm experiencing a strange problem that I believe is related to ADO.NET
> but I can't say for sure.
>
> I have a simple ASP.NET reporting interface to a SQL Server 2000
> database. One report that we run returns a listing of community
> members and their contact information using a stored procedure.
> Depending on the selected community, this can return from a hundred to
> over 1000 rows. Occasionally, the report stops running when a
> community with large membership is run -- the report hangs for a while
> and then comes back empty (no dataset). If I try to run the stored
> procedure directly with the same parameters, everything seems perfectly
> fine. I can temporarily fix the problem by simply running an ALTER
> PROCEDURE statement without making a single change to the procedure.
> The report will now run fine for several days until it eventually stops
> again.
>
> I can't reproduce the problem in my development environment.
It sounds that you run into a command timeout, and the error message
is then thrown away.
I assume that when you run the procedure directly afterwards, that you
are running it from Query Analyzer.
Next time this happens, before you run the procedure in Query Analyzer,
issue this command:
SET ARITHABORT OFF
My prediction is that it will now run as slow as it did ASP .Net.
As you may know SQL Server creates a query plan for a stored procedure
when you run it the first time, and this plan is put into cache.
Now, there can be more than one plan for the same procedure, because
of the different set options. For a discussion on this see
http://www.karaszi.com/SQLServer/info_sp_recompile_set.asp.
All modern client APIs uses the same SET options by default. Query
Analyzer uses a different default on one point: it runs with SET
ARITHABORT ON, which a client API does not.
Therefore when you run the procedure from QA, you will get a different
plan than you did for the ASP .Net client.
Next phenomenon is something called "parameter sniffing". When SQL Server
creates the query plan for a stored procedures, it looks at the input
parameter for the first invocation. My guess is that the weh page runs with
a plan that is good for a small selection. Typically there will be no
plan in cache which matches the settings for QA, so you will get a plan
which is better fit for the larger selection.
Note here that this does not say that things will faster if ARITHABORT
is ON. Had the defaults been in the reverse, you would have seen the
same behaviour. (With one qualification: ARITHABORT must be ON for
indexes on computed columns and views to be used, so if such are involved
it can make a lot of difference.)
Exactly what is the best resolution for your situation is difficult to
say with the amount of information given. If you can live with the slow
response time on large selections, set the CommandTimeout on the Connection
object to 0, to prevent timeouts from happenning. (There was a bug in
earlier versions of SqlClient where 0 was interpreted as 0. If you have an
old version of .Net Fx 1.x, you may have to set the command timeout to 32767
instead.)
If that is not feasible you may have to review indexing and also examine
the query plan in more detail.
--
Erland Sommarskog, SQL Server MVP, esquel@sommarskog.se
Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/prodtechnol/sql/2005/downloads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinfo/previousversions/books.mspx
Navigation:
[Reply to this message]
|