Compilation Locks

  • i generally don't use recompile option for my procs... execution plan is created the first time stored proc is executed and then it takes less time to execute...

    plz. suggest... what are the pros & cons of recompile option.

  • ziangij (5/11/2010)


    plz. suggest... what are the pros & cons of recompile option.

    Parameter sniffing.

    Basically, SQL Server has three ways to deal with constant values in a query:

    a) If it's a constant (e.g. WHERE Age = 35), that value is used to optimize. SQL Server will find a plan that is most efficient for that value.

    b) If it's a variable (e.g. WHERE Age = @Age), the run-time value is not yet knwon when the query is optimized. Statistical information about the average spread of values in the Age column is used to optimze. The plan SQL Server creates will work good for most values, but might not be optimal for atypical values. If, for instance, a large majority of rows will have an age over 65 and only a small minority will have a younger age (as would be the case in a database of dementia patients), the plan will be optimal when @Age is 80, but less so when @Age is 43.

    c) If it's a parameter in a procedure (e.g. CREATE PROC Something @Age int AS .... WHERE Age = @Age), then SQL Server will use ("sniff") the value passed to the parameter when the plan gets created, and find a plan that is optimal for that value. Since the plan goes into cache for future reuse, subsequent executions of the procedure will use the same plan, even if they are called with a different parameter value. In the above case, if the first execution of the procedure happens to use @Age = 43, then it is possible that all future executions with a higher value for @Age are very slow, because SQL Server picked a plan that is optimal for values of @Age where only a small minority of rows match.

    In practice, parameter sniffing does more good than it does harm. But in cases where you find it does harm, you can use the RECOMPILE hint to force SQL Server to receompile the plan every time the stored procedure is executed. The benefit is that each execution uses a plan that is optimal for the @Age value passed in (since SQL Server will still sniff the parameter); the down side is that SQL Server has to spend a lot of resources for all those recompilations.


    Hugo Kornelis, SQL Server/Data Platform MVP (2006-2016)
    Visit my SQL Server blog: https://sqlserverfast.com/blog/
    SQL Server Execution Plan Reference: https://sqlserverfast.com/epr/

  • Thanks for the explanation Hugo. The questio happened to fall while I was on vacation and traveling. In addition to your explanation, each database should have a good maintenance plan. Within that plan should be the updating of statistics on the various indexes as well as rebuilding indexes that need it. I also use a DBCC UPDATEUSAGE as well. After all of my maintenance is completed, I want to ensure that the various stroed procedures are using an optimal QueryPlan. So, the last thing I do is to perform a recompile of all stored procedures and triggers. Ultimately, this will force the procedures to reaquire a new queryplan the first time that they are run.

    Additionally, within your explanation, you should go a bit further. It slips me right this moment which hint it is, but for the scenario you describe, there is a hint that can be used in order to have the procedure use the queryplan for the longest running parameter. this takes some effort to identify, but works. I found it while trying to quell an attempted developer revolt, in that the developers wanted to recompile procedures each time that they ran. In a 1200 user high transaction database, where some of these procedures are called literally a hundred times an hour, could be a problem. I will lookup the hint and post it later.

    Steve Jimmo
    Sr DBA
    “If we ever forget that we are One Nation Under God, then we will be a Nation gone under." - Ronald Reagan

  • sjimmo (5/12/2010)


    It slips me right this moment which hint it is, but for the scenario you describe, there is a hint that can be used in order to have the procedure use the queryplan for the longest running parameter.

    I think you are referring to the OPTIMIZE FOR option, right?

    You can use this to force optimization for the "most often" used vlaue (getting the best performance in most cases, but worse -potentially much worse- in rare cases).

    Or you can use it to force optimization for a value that will result in a plan that might not be optimal for all values, but will never hit extreme execution times.

    [funny fact - I am typing this right after identifying a query ona customer site where the optimizer decided on a nested loops join and a table scan, based on an estimate of 1 input row; the actual row count turned out to be over 20,000 so a 25,000+-row table got scanned over 20,000 times... - that would be the extreme execution time]


    Hugo Kornelis, SQL Server/Data Platform MVP (2006-2016)
    Visit my SQL Server blog: https://sqlserverfast.com/blog/
    SQL Server Execution Plan Reference: https://sqlserverfast.com/epr/

  • I think you are referring to the OPTIMIZE FOR option, right?

    That is the one. Yes there is a down side to it, as with most hints.

    Unfortunately, many think that a hint is law, and have spent many hours debating hints, as well as showing hints that work and then not work because the optimizeer deemed that it knew better.

    I have not worked with this one yet, but think it is coming with a specific issue. Thanks for the info of your experience.

    Steve Jimmo
    Sr DBA
    “If we ever forget that we are One Nation Under God, then we will be a Nation gone under." - Ronald Reagan

  • sjimmo (5/12/2010)


    Unfortunately, many think that a hint is law, and have spent many hours debating hints, as well as showing hints that work and then not work because the optimizeer deemed that it knew better.

    Well, actually hints are law. The term "optimizer hint" is highly misleading; "optimizer directive" would have been better. If you use an index hint, the optimizer WILL use that index for the query. If you specify to use hash joins, you WILL get hash joins. No matter how high the cost and how much cheaper an unhinted plan would have been.

    If you have any evidence to the contrary, please let me know - it's quite likely to be a bug.


    Hugo Kornelis, SQL Server/Data Platform MVP (2006-2016)
    Visit my SQL Server blog: https://sqlserverfast.com/blog/
    SQL Server Execution Plan Reference: https://sqlserverfast.com/epr/

  • Hugo,

    Mine has been more in the rowlock, nolock and tablock hints. I have had cases where the optimizer determined that the tablock was more effective than a rowlock and escalated it as such. Possibly a bug, won't wswear to it as my understanding has been that this is the way that it should be.

    Thanks

    Steve Jimmo
    Sr DBA
    “If we ever forget that we are One Nation Under God, then we will be a Nation gone under." - Ronald Reagan

  • sjimmo (5/12/2010)


    Hugo,

    Mine has been more in the rowlock, nolock and tablock hints. I have had cases where the optimizer determined that the tablock was more effective than a rowlock and escalated it as such. Possibly a bug, won't wswear to it as my understanding has been that this is the way that it should be.

    Thanks

    Ah, that's what you meant.

    This is not a bug. Rowlock and pagelock are mutually exclusive, and both state to use either row locks or page locks as long as escalation to table locks is not required. The pagelock hint tells SQL Server to simply forego the stage of locking individual pages or individual rows and lock the entire table right at once.

    EDIT: Corrected a very stupid eror - thanks, Adi, for pointing it out!


    Hugo Kornelis, SQL Server/Data Platform MVP (2006-2016)
    Visit my SQL Server blog: https://sqlserverfast.com/blog/
    SQL Server Execution Plan Reference: https://sqlserverfast.com/epr/

  • This is not a bug. Rowlock and pagelock are mutually exclusive, and both state to use either row locks or page locks as long as escalation to page locks is not required. The pagelock hint tells SQL Server to simply forego the stage of locking individual pages or individual rows and lock the entire table right at once.

    Exactly. As for the index hints, I knew that one. But thanks for the confirmation.

    Steve Jimmo
    Sr DBA
    “If we ever forget that we are One Nation Under God, then we will be a Nation gone under." - Ronald Reagan

  • This is not a bug. Rowlock and pagelock are mutually exclusive, and both state to use either row locks or page locks as long as escalation to page locks is not required.

    I think that lock escalation can't escalate to page lock. If I'm not mistaken until SQL Server 2008 lock escalation could escalate directly to table lock and since SQL Server 2008 if the table is partitioned, it can escalate to lock a partition in the table (or few partitions if needed).

    Adi

    --------------------------------------------------------------
    To know how to ask questions and increase the chances of getting asnwers:
    http://www.sqlservercentral.com/articles/Best+Practices/61537/

    For better answers on performance questions, click on the following...
    http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

  • Adi Cohn-120898 (5/12/2010)


    This is not a bug. Rowlock and pagelock are mutually exclusive, and both state to use either row locks or page locks as long as escalation to page locks is not required.

    I think that lock escalation can't escalate to page lock. If I'm not mistaken until SQL Server 2008 lock escalation could escalate directly to table lock and since SQL Server 2008 if the table is partitioned, it can escalate to lock a partition in the table (or few partitions if needed).

    Adi

    Oops. Stupid mistake. My mind said table lock, my fingers typed something else.

    Thanks for pointing it out; I'll see if I can edit the post.


    Hugo Kornelis, SQL Server/Data Platform MVP (2006-2016)
    Visit my SQL Server blog: https://sqlserverfast.com/blog/
    SQL Server Execution Plan Reference: https://sqlserverfast.com/epr/

  • Well I selected both the answers required to get the green tick, but I am pretty sure the 'answer' is incorrect.

    Sure, not schema-qualifying the procedure name leads to compilation locks, but not being the owner of the procedure is not sufficient to do so.

    "The user that runs the stored procedure is not the owner of the procedure." should not be a correct answer here.

  • Hugo Kornelis (5/12/2010)


    Well, actually hints are law. The term "optimizer hint" is highly misleading; "optimizer directive" would have been better. If you use an index hint, the optimizer WILL use that index for the query. If you specify to use hash joins, you WILL get hash joins. No matter how high the cost and how much cheaper an unhinted plan would have been. If you have any evidence to the contrary, please let me know - it's quite likely to be a bug.

    Even "optimiser directive" doesn't quite capture it, since not all 'hints' apply to the optimiser. Some hints (like NOWAIT, REPEATABLEREAD, IGNORE_TRIGGERS) are only used by the execution engine. Other hints (like KEEPIDENTITY) materially change the effect of the query.

    I prefer to think of the true optimiser hints as 'implementation rule switches', since they affect which physical implementations are available to the optimiser as it explores the plan space.

    Given the wide range of effects on various stages of query execution, I think 'hint' is as good a term as any, though undoubtedly a flawed one.

Viewing 13 posts - 16 through 27 (of 27 total)

You must be logged in to reply to this topic. Login to reply