Very strange behaviour - Multiple Exec plans - Attached is the complete code

  • I have been battling for weeks on this issue, i was able to resolve the issue but i don't the exact root cause. I am posting complete code, would like to know feedback from others. Issue is that a new execution plan is created from scratch for every execution. Temp table created outside the scope of the sproc is causing the issue, but what i dont get is there is section of code which doesn't even satisfy the condition but seems like is compiled. Please execute the entire script to get better idea.

    Sample Sproc

    CREATE procedure dbo.Test_Sproc @Debug BIT = 0

    as

    select getdate()

    if @Debug =1

    begin

    select * from #test

    end

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

    Check exec plan

    select * from(

    SELECT cp.objtype AS PlanType,

    Object_name(st.objectid, st.dbid) AS ObjectName,

    cp.refcounts AS ReferenceCounts,

    cp.usecounts AS UseCounts,

    st.TEXT AS SQLBatch,

    qp.query_plan AS QueryPlan,

    Cp.Plan_Handle As PlanHandle

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.Dm_exec_query_plan(cp.plan_handle) AS qp

    CROSS APPLY sys.Dm_exec_sql_text(cp.plan_handle) AS st

    ) a

    where a.ObjectName='Test_Sproc'

    Now you should see one exec plan, re-run the entire batch and check the number of execution plans, you should be seeing two. Any idea why?

  • curious_sqldba (4/10/2013)


    I have been battling for weeks on this issue, i was able to resolve the issue but i don't the exact root cause. I am posting complete code, would like to know feedback from others. Issue is that a new execution plan is created from scratch for every execution. Temp table created outside the scope of the sproc is causing the issue, but what i dont get is there is section of code which doesn't even satisfy the condition but seems like is compiled. Please execute the entire script to get better idea.

    Sample Sproc

    CREATE procedure dbo.Test_Sproc @Debug BIT = 0

    as

    select getdate()

    if @Debug =1

    begin

    select * from #test

    end

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

    Check exec plan

    select * from(

    SELECT cp.objtype AS PlanType,

    Object_name(st.objectid, st.dbid) AS ObjectName,

    cp.refcounts AS ReferenceCounts,

    cp.usecounts AS UseCounts,

    st.TEXT AS SQLBatch,

    qp.query_plan AS QueryPlan,

    Cp.Plan_Handle As PlanHandle

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.Dm_exec_query_plan(cp.plan_handle) AS qp

    CROSS APPLY sys.Dm_exec_sql_text(cp.plan_handle) AS st

    ) a

    where a.ObjectName='Test_Sproc'

    Now you should see one exec plan, re-run the entire batch and check the number of execution plans, you should be seeing two. Any idea why?

    The way everything is posted it is hard to tell what makes up the complete script. A guess I have is that there is no GO after the END that you "think" marks the end of the stored procedure but actually doesn't.

  • Lynn Pettis (4/10/2013)


    curious_sqldba (4/10/2013)


    I have been battling for weeks on this issue, i was able to resolve the issue but i don't the exact root cause. I am posting complete code, would like to know feedback from others. Issue is that a new execution plan is created from scratch for every execution. Temp table created outside the scope of the sproc is causing the issue, but what i dont get is there is section of code which doesn't even satisfy the condition but seems like is compiled. Please execute the entire script to get better idea.

    Sample Sproc

    CREATE procedure dbo.Test_Sproc @Debug BIT = 0

    as

    select getdate()

    if @Debug =1

    begin

    select * from #test

    end

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

    Check exec plan

    select * from(

    SELECT cp.objtype AS PlanType,

    Object_name(st.objectid, st.dbid) AS ObjectName,

    cp.refcounts AS ReferenceCounts,

    cp.usecounts AS UseCounts,

    st.TEXT AS SQLBatch,

    qp.query_plan AS QueryPlan,

    Cp.Plan_Handle As PlanHandle

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.Dm_exec_query_plan(cp.plan_handle) AS qp

    CROSS APPLY sys.Dm_exec_sql_text(cp.plan_handle) AS st

    ) a

    where a.ObjectName='Test_Sproc'

    Now you should see one exec plan, re-run the entire batch and check the number of execution plans, you should be seeing two. Any idea why?

    The way everything is posted it is hard to tell what makes up the complete script. A guess I have is that there is no GO after the END that you "think" marks the end of the stored procedure but actually doesn't.

    You can add a GO there, this is just a example. My intent here was to depict a strange scenario where execution plans are not being cached. Did you try executing the code?

  • curious_sqldba (4/10/2013)


    Lynn Pettis (4/10/2013)


    curious_sqldba (4/10/2013)


    I have been battling for weeks on this issue, i was able to resolve the issue but i don't the exact root cause. I am posting complete code, would like to know feedback from others. Issue is that a new execution plan is created from scratch for every execution. Temp table created outside the scope of the sproc is causing the issue, but what i dont get is there is section of code which doesn't even satisfy the condition but seems like is compiled. Please execute the entire script to get better idea.

    Sample Sproc

    CREATE procedure dbo.Test_Sproc @Debug BIT = 0

    as

    select getdate()

    if @Debug =1

    begin

    select * from #test

    end

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

    Check exec plan

    select * from(

    SELECT cp.objtype AS PlanType,

    Object_name(st.objectid, st.dbid) AS ObjectName,

    cp.refcounts AS ReferenceCounts,

    cp.usecounts AS UseCounts,

    st.TEXT AS SQLBatch,

    qp.query_plan AS QueryPlan,

    Cp.Plan_Handle As PlanHandle

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.Dm_exec_query_plan(cp.plan_handle) AS qp

    CROSS APPLY sys.Dm_exec_sql_text(cp.plan_handle) AS st

    ) a

    where a.ObjectName='Test_Sproc'

    Now you should see one exec plan, re-run the entire batch and check the number of execution plans, you should be seeing two. Any idea why?

    The way everything is posted it is hard to tell what makes up the complete script. A guess I have is that there is no GO after the END that you "think" marks the end of the stored procedure but actually doesn't.

    You can add a GO there, this is just a example. My intent here was to depict a strange scenario where execution plans are not being cached. Did you try executing the code?

    Nope, I haven't. As I said in my previous post, the way you have the code broken up in your post I don't know what code to run as a single batch.

    Care to elucidate on this?

  • Lynn Pettis (4/10/2013)


    curious_sqldba (4/10/2013)


    Lynn Pettis (4/10/2013)


    curious_sqldba (4/10/2013)


    I have been battling for weeks on this issue, i was able to resolve the issue but i don't the exact root cause. I am posting complete code, would like to know feedback from others. Issue is that a new execution plan is created from scratch for every execution. Temp table created outside the scope of the sproc is causing the issue, but what i dont get is there is section of code which doesn't even satisfy the condition but seems like is compiled. Please execute the entire script to get better idea.

    Sample Sproc

    CREATE procedure dbo.Test_Sproc @Debug BIT = 0

    as

    select getdate()

    if @Debug =1

    begin

    select * from #test

    end

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

    Check exec plan

    select * from(

    SELECT cp.objtype AS PlanType,

    Object_name(st.objectid, st.dbid) AS ObjectName,

    cp.refcounts AS ReferenceCounts,

    cp.usecounts AS UseCounts,

    st.TEXT AS SQLBatch,

    qp.query_plan AS QueryPlan,

    Cp.Plan_Handle As PlanHandle

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.Dm_exec_query_plan(cp.plan_handle) AS qp

    CROSS APPLY sys.Dm_exec_sql_text(cp.plan_handle) AS st

    ) a

    where a.ObjectName='Test_Sproc'

    Now you should see one exec plan, re-run the entire batch and check the number of execution plans, you should be seeing two. Any idea why?

    The way everything is posted it is hard to tell what makes up the complete script. A guess I have is that there is no GO after the END that you "think" marks the end of the stored procedure but actually doesn't.

    You can add a GO there, this is just a example. My intent here was to depict a strange scenario where execution plans are not being cached. Did you try executing the code?

    Nope, I haven't. As I said in my previous post, the way you have the code broken up in your post I don't know what code to run as a single batch.

    Care to elucidate on this?

    i) First run the script to create the sproc from first block.

    ii) Execute the entire script from second block.

    iii) run the third script to make sure you see the execution plan.

    iv) now open another query window,run the script from second block.

    v) again run the script from third block, you will see another exec plan created.

    Hope this helps.

  • I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

  • Lynn Pettis (4/10/2013)


    I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

    Yup i totally get that. However if you carefully look at the sproc we are not even hitting the condition i.e If Debug=1 because we are executing the sproc as exec dbo.Test_Sproc @Debug=0 , why would it matter what is inside the If condition if we are not even hitting that condition?

  • curious_sqldba (4/11/2013)


    Lynn Pettis (4/10/2013)


    I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

    Yup i totally get that. However if you carefully look at the sproc we are not even hitting the condition i.e If Debug=1 because we are executing the sproc as exec dbo.Test_Sproc @Debug=0 , why would it matter what is inside the If condition if we are not even hitting that condition?

    Because plan generation comes before execution.

    Try the following just as you did with your code:

    CREATE procedure dbo.Test_Sproc1

    @Debug BIT = 0

    as

    declare @SQLCmd varchar(8000);

    set @SQLCmd = 'select * from #test';

    select getdate()

    if @Debug =1

    begin

    exec (@SQLCmd);

    end

    GO

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc1 @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

    select * from(

    SELECT cp.objtype AS PlanType,

    Object_name(st.objectid, st.dbid) AS ObjectName,

    cp.refcounts AS ReferenceCounts,

    cp.usecounts AS UseCounts,

    st.TEXT AS SQLBatch,

    qp.query_plan AS QueryPlan,

    Cp.Plan_Handle As PlanHandle

    FROM sys.dm_exec_cached_plans AS cp

    CROSS APPLY sys.Dm_exec_query_plan(cp.plan_handle) AS qp

    CROSS APPLY sys.Dm_exec_sql_text(cp.plan_handle) AS st

    ) a

    where a.ObjectName='Test_Sproc1'

  • I only see one plan for the conditional select, the same plan whichever parameter I use. It's what I'd expect to see. Am I missing something?

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • ChrisM@Work (4/11/2013)


    I only see one plan for the conditional select, the same plan whichever parameter I use. It's what I'd expect to see. Am I missing something?

    If you run the following from two different sessions (I know I did), you get two plans generated for the stored proc.

    create table #test (name nvarchar(max))

    insert into #test values( 'John')

    exec dbo.Test_Sproc @Debug=0 -- notice i am passing 0 and not 1 , so the block of code shouldn't be executed

    drop table #test

  • Lynn Pettis (4/10/2013)


    I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

    A new plan for each new session, even. There's some useful info here.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • ChrisM@Work (4/11/2013)


    Lynn Pettis (4/10/2013)


    I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

    A new plan for each new session, even. There's some useful info here.

    Still doesn't answer my question. My temp is executed in block of where the condition is never used, but still there are multiple exec plans. Please go to the original post for more details.

  • curious_sqldba (4/11/2013)


    ChrisM@Work (4/11/2013)


    Lynn Pettis (4/10/2013)


    I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

    A new plan for each new session, even. There's some useful info here.

    Still doesn't answer my question. My temp is executed in block of where the condition is never used, but still there are multiple exec plans. Please go to the original post for more details.

    It is never used when the procedure is executed, but SQL Server still generates a plan for the SQL statement in the IF block. Compilation does not evaluate the IF clause, that is done during execution, after the plan is generated.

  • curious_sqldba (4/11/2013)


    ChrisM@Work (4/11/2013)


    Lynn Pettis (4/10/2013)


    I think I know why, the table #test are different tables when the stored procedure is run in different sessions. Therefore you will get separate plans for the execution of the stored procedure. If you run the second batch a second time in the same session it reuses the plan originally created.

    Edit: Actually the temporary table #test is different when created from different sessions.

    A new plan for each new session, even. There's some useful info here.

    Still doesn't answer my question. My temp is executed in block of where the condition is never used, but still there are multiple exec plans. Please go to the original post for more details.

    I'm not quite sure what you mean. The article I referenced stated that for any chance of plan reuse, a temp table used by a stored procedure should be declared within it, not outside.

    You may be missing a point about plan generation and conditional statements which is covered very well here[/url]: "The optimiser processes all branches of a conditional no matter which branch will be taken during execution, even if the branch can never be executed".

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • And the reason you get a separate plan for the execution of the same procedure from different sessions is that the procedure is actually accessing a completely different table in those sessions. The table #test in session 1 is not the same #test in session 2.

Viewing 15 posts - 1 through 15 (of 16 total)

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