ADO.NET problem?

B

billmiami2

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.

Does anyone have any ideas as to what this could be?

Bill E.
Hollywood, FL
 
E

Erland Sommarskog

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, (e-mail address removed)

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
 
B

billmiami2

Erland,

Thanks for the response as always.

I'll try the SET ARITHABORT OFF in query analyzer the next time it
occurs. I would be very interested to see what happens in this case.

When it's working, the query runs very quickly, even when 1000 rows are
returned. This is true for both query analyzer and the web page. Of
course when it breaks down, the web page stops but query analyzer still
runs it in a split second.

I certainly know that SQL Server creates an execution plan on the first
run, but I never thought that there would be two execution plans and
certainly not a different one for a large resultset vs. a small
resultset.

The query contains a large number of subqueries which I think might be
confusing the optimizer. Perhaps a solution using some temp tables
will help--I'll have to see.

No, setting the timeout longer won't suffice, especially when I know
that the query has the potential to run quickly.

Bill
 
E

Erland Sommarskog

When it's working, the query runs very quickly, even when 1000 rows are
returned. This is true for both query analyzer and the web page. Of
course when it breaks down, the web page stops but query analyzer still
runs it in a split second.

I certainly know that SQL Server creates an execution plan on the first
run, but I never thought that there would be two execution plans and
certainly not a different one for a large resultset vs. a small
resultset.

When I said that there could be different plans for large and small result
sets that was a simplification. Consider this simple procedure:

CREATE PROCEDURE get_count @Val int, @Count OUTPUT AS
SELECT @Count = count(DISTINCT col1) FROM tbl WHERE col2 = @Val

Assume that here is a non-clustered index on col2 and that this index
does not include col1, nor is col1 in the clustred index. Assume further
that the distribution of col2 is uneven. 30% of the rows have 0 in this
column, the remaining rows have scattered value.

If the first invocation is for @Val = 10, the optimizer will use the
index to compute the query. But if the first invocation is for @Val = 0,
the optimizer will scan the table, because that is faster in this case.


Now, exactly what is going in your application I don't know. But it
sounds as if the procedure is recompiled at some point, and the input
values at that point are very atypical, leading to a poor execution plan
for regular values. That poor plan could affect smaller selection, but
you could be lucky that the cost is less noticeable in this case.

But why would the procedure be recompiled? There are several reasons
for this. One is change in statistics. By default SQL Server maintains
statistics on the tables, and when they change for a table, referring
procedures will be recompiled. It could also be that the plan falls out
of cache if there is memory pressure, and the procedure has not been
used for a while.

One thing you could consider is to add WITH RECOMPILE to the procedure
definition. In this case the procedure is recompiled each time it is
invoked, and nothing is put into cache. The recompile has a cost, but
at least you prevent a bad plan from sticking.



--
Erland Sommarskog, SQL Server MVP, (e-mail address removed)

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
 
B

billmiami2

Erland,

This occurred again so I immediately tried the SET ARITHABORT OFF
option and you were correct--the query ran slowly in query analyzer as
well.

By the way, we discovered that this problem is occurring not only with
the member listing procedure but also a member search procedure when an
address search option is selected. Other search options do not cause
problems. Therefore, I am beginning to suspect that something is wrong
with our address table. Perhaps we have some fragmentation in an index
or something related. In the interim, I've added the WITH RECOMPILE
clause to these two procedures to ensure that they do not run slowly or
time out. Fortunately, this doesn't appear to be slowing them down
much.

Bill
 
E

Erland Sommarskog

By the way, we discovered that this problem is occurring not only with
the member listing procedure but also a member search procedure when an
address search option is selected. Other search options do not cause
problems. Therefore, I am beginning to suspect that something is wrong
with our address table. Perhaps we have some fragmentation in an index
or something related.

You can examine fragmentation with DBCC SHOWCONTIG. But I would not expect
that to be the problem, since you apparently get different plans.

But statistics may not be current. By default, SQL Server updates statistics
automatically, but for large tables it may not be often enough.



--
Erland Sommarskog, SQL Server MVP, (e-mail address removed)

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
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Members online

No members online now.

Forum statistics

Threads
473,769
Messages
2,569,582
Members
45,066
Latest member
VytoKetoReviews

Latest Threads

Top