Tuning SQL Server query

  • Hi All,

    My query when run I get a merge join with SORT. I want to avoid this sorting which is expensive. How do I tune It

    select @QTY_cost = (select round(SUM(QTY),0)QTY

    from(

    SELECT TXN.Rubel_ID,

    TXN.RUBEL_TRANSACTION_ID,

    txn.TRANSACTION_CODE,

    txn.SEC_TYPE_CODE1,

    txn.SEC_TYPE_CODE2,

    txn.SECURITY_ID1 securityid,

    txn.SECURITY_ID2 securityid2,

    txn.Fn_bacashcalculation(TXN.Transaction_Code, TXN.SEC_TYPE_CODE1, TXN.Sec_Type_Code2, TXN.TRADE_AMOUNT, 'Y') AS QTY

    FROM TXN.TRANSACTION_DETAILS TXN with (nolock)

    WHERE txn.RUBEL_ID = @Rubel_ID

    AND txn.SECURITY_ID1 = @Security_ID

    and NOT (TXN.TRANSACTION_CODE IN ('dp','wd') and txn.SECURITY_ID1 = txn.SECURITY_ID2)

    and TXN.TRADE_DATE <= @Report_dt

    and not (TXN.TRANSACTION_CODE IN ('sa','pa') and ISNULL(SETTLE_DATE,TRADE_DATE) > @Report_dt)

    AND TXN.Transaction_Code not in ( 'in','dv')

    and txn.END_DT is null

    UNION ALL

    SELECT txn.Rubel_ID,

    txn.RUBEL_TRANSACTION_ID,

    txn.TRANSACTION_CODE,

    txn.SEC_TYPE_CODE1,

    txn.SEC_TYPE_CODE2,

    txn.security_id2 securityid,

    txn.SECURITY_ID1 securityid2 ,

    txn.Fn_bacashcalculation(TXN.TRANSACTION_CODE, TXN.SEC_TYPE_CODE1, TXN.SEC_TYPE_CODE2, TXN.TRADE_AMOUNT, 'N') AS QTY

    FROM TXN.TRANSACTION_DETAILS TXN with (nolock)

    WHERE txn.RUBEL_ID = @Rubel_ID

    AND txn.SECURITY_ID2 = @Security_ID

    and NOT (TXN.TRANSACTION_CODE IN ('dp','wd') and txn.SECURITY_ID1 = txn.SECURITY_ID2)

    and TRADE_DATE <= @Report_dt

    and not (TXN.TRANSACTION_CODE IN ('sa','pa') and ISNULL(SETTLE_DATE,TRADE_DATE)> @Report_dt)

    and txn.END_DT is null

    )X )

    "More Green More Oxygen !! Plant a tree today"

  • Table definitions, index definitions and execution plan please.

    Why do you think the sort is a problem?

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    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
  • And here it is again for those who would prefer to see the query formatted:

    select @QTY_cost = (select round(sum(QTY), 0) QTY

    from (select TXN.Rubel_ID

    ,TXN.RUBEL_TRANSACTION_ID

    ,TXN.TRANSACTION_CODE

    ,TXN.SEC_TYPE_CODE1

    ,TXN.SEC_TYPE_CODE2

    ,TXN.SECURITY_ID1 securityid

    ,TXN.SECURITY_ID2 securityid2

    ,TXN.Fn_bacashcalculation(TXN.Transaction_Code, TXN.SEC_TYPE_CODE1, TXN.Sec_Type_Code2, TXN.TRADE_AMOUNT, 'Y') as QTY

    from TXN.TRANSACTION_DETAILS TXN with (nolock)

    where TXN.RUBEL_ID = @Rubel_ID

    and TXN.SECURITY_ID1 = @Security_ID

    and not (TXN.TRANSACTION_CODE in ('dp', 'wd')

    and TXN.SECURITY_ID1 = TXN.SECURITY_ID2

    )

    and TXN.TRADE_DATE <= @Report_dt

    and not (TXN.TRANSACTION_CODE in ('sa', 'pa')

    and isnull(SETTLE_DATE, TRADE_DATE) > @Report_dt

    )

    and TXN.Transaction_Code not in ('in', 'dv')

    and TXN.END_DT is null

    union all

    select TXN.Rubel_ID

    ,TXN.RUBEL_TRANSACTION_ID

    ,TXN.TRANSACTION_CODE

    ,TXN.SEC_TYPE_CODE1

    ,TXN.SEC_TYPE_CODE2

    ,TXN.security_id2 securityid

    ,TXN.SECURITY_ID1 securityid2

    ,TXN.Fn_bacashcalculation(TXN.TRANSACTION_CODE, TXN.SEC_TYPE_CODE1, TXN.SEC_TYPE_CODE2, TXN.TRADE_AMOUNT, 'N') as QTY

    from TXN.TRANSACTION_DETAILS TXN with (nolock)

    where TXN.RUBEL_ID = @Rubel_ID

    and TXN.SECURITY_ID2 = @Security_ID

    and not (TXN.TRANSACTION_CODE in ('dp', 'wd')

    and TXN.SECURITY_ID1 = TXN.SECURITY_ID2

    )

    and TRADE_DATE <= @Report_dt

    and not (TXN.TRANSACTION_CODE in ('sa', 'pa')

    and isnull(SETTLE_DATE, TRADE_DATE) > @Report_dt

    )

    and TXN.END_DT is null

    ) X

    );

    I suggest you get ready to defend your use of (NOLOCK) ๐Ÿ˜‰

    If you haven't even tried to resolve your issue, please don't expect the hard-working volunteers here to waste their time providing links to answers which you could easily have found yourself.

  • Quick review reveals Scalar UDFs, NOT INs and Functions Around Columns in WHERE clause. 2 of those 3 are BAD BAD BAD things todo in a query and the other (NOT IN) can really cause issues with effective optimization. With all that lord only knows what else is suboptimal on the server/database/schema/application.

    And I agree, what about the SORT makes it so bad you want to get rid of it?

    Best,
    Kevin G. Boles
    SQL Server Consultant
    SQL MVP 2007-2012
    TheSQLGuru on googles mail service

  • TheSQLGuru (5/18/2015)


    And I agree, what about the SORT makes it so bad you want to get rid of it?

    Personally I can't even see where a merge join would be coming from, since both branches of the UNION have a single table in them. Unless it's actually a view.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    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
  • GilaMonster (5/18/2015)


    TheSQLGuru (5/18/2015)


    And I agree, what about the SORT makes it so bad you want to get rid of it?

    Personally I can't even see where a merge join would be coming from, since both branches of the UNION have a single table in them. Unless it's actually a view.

    Could be view, or maybe inside the scalar udf?

    Best,
    Kevin G. Boles
    SQL Server Consultant
    SQL MVP 2007-2012
    TheSQLGuru on googles mail service

  • And then of course, there is the NOLOCK hint with a query that appears to be working with financial data.

  • This might at least help a bit, but it won't address the main problems of the query (user defined scalar function and function on columns in the where clause or others that we can't see).

    select @QTY_cost = (select round(sum(TXN.Fn_bacashcalculation(TXN.Transaction_Code,

    TXN.SEC_TYPE_CODE1,

    TXN.Sec_Type_Code2,

    TXN.TRADE_AMOUNT,

    'Y') +

    TXN.Fn_bacashcalculation(TXN.TRANSACTION_CODE,

    TXN.SEC_TYPE_CODE1,

    TXN.SEC_TYPE_CODE2,

    TXN.TRADE_AMOUNT,

    'N')), 0) as QTY

    from TXN.TRANSACTION_DETAILS TXN with (nolock) --Why NOLOCK? Are you fine with inconsistent results?

    where TXN.RUBEL_ID = @Rubel_ID

    and TXN.SECURITY_ID2 = @Security_ID

    and not (TXN.TRANSACTION_CODE in ('dp', 'wd')

    and TXN.SECURITY_ID1 = TXN.SECURITY_ID2

    )

    and TRADE_DATE <= @Report_dt

    and not (TXN.TRANSACTION_CODE in ('sa', 'pa')

    and isnull(SETTLE_DATE, TRADE_DATE) > @Report_dt

    )

    and TXN.END_DT is null

    );

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Thanks for replying back now, I am going to optimize the code as suggested and update the group.

    "More Green More Oxygen !! Plant a tree today"

  • Minaz Amin (6/23/2015)


    Thanks for replying back now, I am going to optimize the code as suggested and update the group.

    Do you realize that you still have performance issues that are not going away with the posted solutions?

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • TheSQLGuru (5/18/2015)


    GilaMonster (5/18/2015)


    TheSQLGuru (5/18/2015)


    And I agree, what about the SORT makes it so bad you want to get rid of it?

    Personally I can't even see where a merge join would be coming from, since both branches of the UNION have a single table in them. Unless it's actually a view.

    Could be view, or maybe inside the scalar udf?

    Won't be inside the UDF, since the exec plan will just show a Compute Scalar for that. View would be my guess.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    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
  • I will test on DEV first and follow up with all the env.

    "More Green More Oxygen !! Plant a tree today"

  • Minaz Amin (6/24/2015)


    I will test on DEV first and follow up with all the env.

    Can you post the Actual Execution Plan as a .sqlplan attachment? This would help folks evaluate tuning opportunities.

    โ€œ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

Viewing 13 posts - 1 through 12 (of 12 total)

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