Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Techniques for improving stored procedure performance Expand / Collapse
Author
Message
Posted Friday, August 23, 2013 9:24 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, September 18, 2014 9:03 AM
Points: 2,030, Visits: 3,443
Hi, SQL land . . .

I realize that this is a general and vague question; for this, I apologize in advance. I'm looking to educate myself, and would appreciate any advice, tips, tricks, and helpful links.

Here's my scenario: I have SQL code that I'm writing (that is getting increasingly complex).

When I run it in SSMS as a standalone query, it flies. I get my results in just a few seconds.

However, when I put the exact same query into a stored procedure (no changes to the code AT ALL, other than putting it into a stored proc and testing it in another query window), it slows to a crawl -- 30+ seconds.

I've already specified the WITH RECOMPILE option. Is there anything else I should look into?
Post #1487877
Posted Friday, August 23, 2013 9:35 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 5:50 AM
Points: 2,856, Visits: 5,124
Does your proc have input parameters which then used directly in WHERE clauses or JOINS?
If so, try to declare local variables at the top of proc, assign them to input param values and use them instead. You may find it will help you better than using WITH RECOMPILE.
Do you run both ways in SSMS?


_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1487889
Posted Friday, August 23, 2013 9:39 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 2:13 PM
Points: 39,866, Visits: 36,208
Parameter sniffing, or possibly lack thereof would be my first guess, but really need to see the procedure to say for sure.


Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1487893
Posted Friday, August 23, 2013 10:05 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, September 18, 2014 9:03 AM
Points: 2,030, Visits: 3,443
Hey Gail -- unfortunately, I'm unable to post the code for security reasons. I suppose I could do a "protect the innocent" rewrite, but alas, I don't have time for that right now.

Eugene Elutin (8/23/2013)
Does your proc have input parameters which then used directly in WHERE clauses or JOINS?
If so, try to declare local variables at the top of proc, assign them to input param values and use them instead. You may find it will help you better than using WITH RECOMPILE.
Do you run both ways in SSMS?


I have input parameters for @startdate and @enddate, but I default them both to null in the stored proc. In my code, I set them to 1/1/1900 and getdate(), respectively. To be honest, I'm not even sure that they're needed, and I might actually take them out completely.
Post #1487909
Posted Friday, August 23, 2013 10:20 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 2:13 PM
Points: 39,866, Visits: 36,208
Ray K (8/23/2013)
I default them both to null in the stored proc. In my code, I set them to 1/1/1900 and getdate(), respectively.


And that's your problem right there.
http://sqlinthewild.co.za/index.php/2008/05/22/parameter-sniffing-pt-3/

If you're going to change the values of parameters, you need to use variables instead. Otherwise the plan is compiled for parameter values of NULL and when it runs with something non-null you have a really, really inappropriate execution plan



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1487919
Posted Friday, August 23, 2013 12:19 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Thursday, September 18, 2014 9:03 AM
Points: 2,030, Visits: 3,443
GilaMonster (8/23/2013)
Ray K (8/23/2013)
I default them both to null in the stored proc. In my code, I set them to 1/1/1900 and getdate(), respectively.


And that's your problem right there.
http://sqlinthewild.co.za/index.php/2008/05/22/parameter-sniffing-pt-3/

If you're going to change the values of parameters, you need to use variables instead. Otherwise the plan is compiled for parameter values of NULL and when it runs with something non-null you have a really, really inappropriate execution plan

And lo and behold, that did it.

Thanks for your help, Gail, as always!
Post #1487971
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse