Prepared vs dynamic SQL odd execution plan

  • I have a SQL statement that is resulting in widely differing execution plans depending on the format of the SQL submitted. The end result of both queries is exactly the same, however one results in an index seek and the other an index scan. I'd like to understand why this is happening and if there's a way to force the plan to use an index seek instead. That said, the straight SQL is:

    UPDATE

    BILL_INSTALLMENT

    SET

    BILL_INSTALLMENT.A_BITM_COMM = 0.00 ,

    BILL_INSTALLMENT.D_BITM_COMM_AC = NULL ,

    BILL_INSTALLMENT.C_BITM_COMM_AC = NULL ,

    BILL_INSTALLMENT.A_BITM_COMM_AC = NULL ,

    BILL_INSTALLMENT.A_INST_MIN_DUE = 44.64 ,

    BILL_INSTALLMENT.D_INST_MIN_DUE_AC = NULL ,

    BILL_INSTALLMENT.C_INST_MIN_DUE_AC = NULL ,

    BILL_INSTALLMENT.A_INST_MIN_DUE_AC = NULL ,

    BILL_INSTALLMENT.A_INST_TOT_PD = 44.64 ,

    BILL_INSTALLMENT.D_INST_TOT_PD_AC = NULL ,

    BILL_INSTALLMENT.C_INST_TOT_PD_AC = NULL ,

    BILL_INSTALLMENT.A_INST_TOT_PD_AC = NULL ,

    BILL_INSTALLMENT.C_BITM_TYP = N'KYS' ,

    BILL_INSTALLMENT.C_INST_PAY_PRY = N'40' ,

    BILL_INSTALLMENT.C_INST_NTC_TYP = 1 ,

    BILL_INSTALLMENT.C_INST_TRN = N'RN' ,

    BILL_INSTALLMENT.D_INST_DUE = '2007-03-21 00:00:00.000' ,

    BILL_INSTALLMENT.N_CLT_ID_UID = 10088 ,

    BILL_INSTALLMENT.D_INST = '2007-03-21 00:00:00.000' ,

    BILL_INSTALLMENT.D_INST_DUE_ORIG = '2007-03-21 00:00:00.000' ,

    BILL_INSTALLMENT.D_INST_SENT_TO_GL = '2007-02-22 00:00:00.000'

    WHERE

    BILL_INSTALLMENT.N_INST_OID = 1001

    Whereas, when I use prepared statement format, I end up executing the following SQL (I'm not including the DECLARE and variable assignment statements to try and shorten this, but they are set correctly):

    UPDATE

    BILL_INSTALLMENT

    SET

    BILL_INSTALLMENT.A_BITM_COMM = @P3 ,

    BILL_INSTALLMENT.D_BITM_COMM_AC = @P4 ,

    BILL_INSTALLMENT.C_BITM_COMM_AC = @P5 ,

    BILL_INSTALLMENT.A_BITM_COMM_AC = @P6 ,

    BILL_INSTALLMENT.A_INST_MIN_DUE = @P7 ,

    BILL_INSTALLMENT.D_INST_MIN_DUE_AC = @P8 ,

    BILL_INSTALLMENT.C_INST_MIN_DUE_AC = @P9 ,

    BILL_INSTALLMENT.A_INST_MIN_DUE_AC = @P10 ,

    BILL_INSTALLMENT.A_INST_TOT_PD = @P11 ,

    BILL_INSTALLMENT.D_INST_TOT_PD_AC = @P12 ,

    BILL_INSTALLMENT.C_INST_TOT_PD_AC = @P13 ,

    BILL_INSTALLMENT.A_INST_TOT_PD_AC = @P14 ,

    BILL_INSTALLMENT.C_BITM_TYP = @P15 ,

    BILL_INSTALLMENT.C_INST_PAY_PRY = @P16 ,

    BILL_INSTALLMENT.C_INST_NTC_TYP = @P17 ,

    BILL_INSTALLMENT.C_INST_TRN = @P18 ,

    BILL_INSTALLMENT.D_INST_DUE = @P19 ,

    BILL_INSTALLMENT.N_CLT_ID_UID = @P25 ,

    BILL_INSTALLMENT.D_INST = @P26 ,

    BILL_INSTALLMENT.D_INST_DUE_ORIG = @P27 ,

    BILL_INSTALLMENT.D_INST_SENT_TO_GL = @P28

    WHERE

    BILL_INSTALLMENT.N_INST_OID = @P29

    When I use the straight-forward SQL my execution plan includes an index seek on the PK field N_INST_OID. When I use the prepared statement format my execution plan includes an index scan on the PK field N_INST_OID. BTW, in case it is relevant, the primary key (@P29) is defined as a decimal(38,0).

  • In your first example, the optimizer can use the value you've passed in (1001) and actually look at the distribution of the index to determine if an index seek could be used. When you run the same query and pass it a parameter instead of an explicit value, the Query Optimizer must look at all of the values in the query and create an execution plan based off of the selectivity of all of the index values. In this case, the Optimizer determines that an index scan would be more efficient. I would guess that your value of 1001 is fairly selective with regards to the other values in the index.

    Does that help?

    John Rowan

    ======================================================
    ======================================================
    Forum Etiquette: How to post data/code on a forum to get the best help[/url] - by Jeff Moden

  • John Rowan (6/11/2008)


    In your first example, the optimizer can use the value you've passed in (1001) and actually look at the distribution of the index to determine if an index seek could be used. When you run the same query and pass it a parameter instead of an explicit value, the Query Optimizer must look at all of the values in the query and create an execution plan based off of the selectivity of all of the index values. In this case, the Optimizer determines that an index scan would be more efficient. I would guess that your value of 1001 is fairly selective with regards to the other values in the index.

    Does that help?

    Thanks for your response...

    Yes, the value of 1001 is the primary key, so the selectivity should be one-to-one. That is part of what confuses me. Regardless of the value of @P29, if it is matching on the PK, why would there be any question on selectivity? Is there a hint, or some other method of getting the optimizer to use a seek?

  • Check this article:

    http://sqlinthewild.co.za/index.php/2008/02/25/parameter-sniffing-pt-2/

    ---- I got this from Gail Shaw.:)

  • That was exactly what I was looking for! Thank you much!!

Viewing 5 posts - 1 through 4 (of 4 total)

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