In Need of some expert query help

  • The below query I have been piecing together is really slow. I was wondering if any of you might be able to give me some ideas with regard to optimizing this. My goal is to create a view then leverage the view for an SSIS project. I'm thinking there MUST be a better solution. Thanks

    SELECT

    'MySource' AS SourceDB,

    'MySite' AS 'SiteName',

    Rtrim(apibh.idvend) AS VendorNumber,

    Rtrim(apibh.idinvc) AS VoucherNumber,

    Sum(apibh.amtgrosdst) AS VoucherTotalDomestic,

    Sum(apibh.amtgrosdst) * ( apibh.exchratehc ) AS VoucherTotalUSD,

    (SELECT DISTINCT ( Sum(p.amtpaym) )

    FROM aptcr r WITH(NOLOCK)

    INNER JOIN aptcp p

    ON r.btchtype = p.batchtype

    AND r.cntbtch = p.cntbtch

    AND r.cntentr = p.cntrmit

    INNER JOIN apibh H

    ON p.idvend = h.idvend

    AND p.idinvc = H.idinvc

    WHERE H.idinvc = apibh.idinvc

    GROUP BY H.idinvc) AS PayAmt,

    (Sum(apibh.amtgrosdst) -

    (SELECT DISTINCT ( Sum(p.amtpaym) )

    FROM aptcr r WITH(NOLOCK)

    INNER JOIN aptcp p

    ON r.btchtype = p.batchtype

    AND r.cntbtch = p.cntbtch

    AND r.cntentr = p.cntrmit

    INNER JOIN apibh H

    ON p.idvend = h.idvend

    AND p.idinvc = H.idinvc

    WHERE H.idinvc = apibh.idinvc

    GROUP BY H.idinvc) ) AS OpenAmountDomestic,

    (Sum(apibh.amtgrosdst) -

    ((SELECT DISTINCT ( Sum(p.amtpaym) )

    FROM aptcr r WITH(NOLOCK)

    INNER JOIN aptcp p

    ON r.btchtype = p.batchtype

    AND r.cntbtch = p.cntbtch

    AND r.cntentr = p.cntrmit

    INNER JOIN apibh H

    ON p.idvend = h.idvend

    AND p.idinvc = H.idinvc

    WHERE H.idinvc = apibh.idinvc

    GROUP BY H.idinvc) ) * ( apibh.exchratehc )) AS OpenAmountUSD,

    (

    Select DATEDIFF(day,(SELECT DISTINCT ( Max(dbo.Udf_convert_int_date(r.datermit)) )

    FROM aptcr r WITH(NOLOCK)

    INNER JOIN aptcp p

    ON r.btchtype = p.batchtype

    AND r.cntbtch = p.cntbtch

    AND r.cntentr = p.cntrmit

    INNER JOIN apibh H

    ON p.idvend = h.idvend

    AND p.idinvc = H.idinvc

    WHERE H.idinvc = apibh.idinvc

    GROUP BY H.idinvc),GETDATE()))AS DueDays,

    '' As AgeDays ,

    (SELECT DISTINCT ( Max(dbo.Udf_convert_int_date(r.datermit)) )

    FROM aptcr r WITH(NOLOCK)

    INNER JOIN aptcp p

    ON r.btchtype = p.batchtype

    AND r.cntbtch = p.cntbtch

    AND r.cntentr = p.cntrmit

    INNER JOIN apibh H

    ON p.idvend = h.idvend

    AND p.idinvc = H.idinvc

    WHERE H.idinvc = apibh.idinvc

    GROUP BY H.idinvc) AS PaidDate,

    dbo.Udf_convert_int_date(apibh.datebus) AS PostedDate,

    dbo.Udf_convert_int_date(apibh.datebus) AS AppliedDate,

    dbo.Udf_convert_int_date(apibh.dateinvc) AS AgingDate,

    dbo.Udf_convert_int_date(apibh.datedue) AS DueDate,

    dbo.Udf_convert_int_date(apibh.dateinvc) AS DocumentDate,

    NULL AS ReceivedDate,

    CASE

    WHEN ( apibh.datedisc ) = 0 THEN NULL

    ELSE dbo.Udf_convert_int_date(apibh.datedisc)

    END AS DiscountDate,

    apibh.codecurn AS CurrencyCode,

    apibh.exchratehc AS EffectiveExchangeRate

    FROM apibh AS APIBH WITH(NOLOCK)

    WHERE 1 = 1

    --AND APIBH.IDINVC = '22036'

    --AND APIBH.IDVEND = 'ABE129'

    GROUP BY ( apibh.idvend ),

    ( apibh.idinvc ),

    ( apibh.amtgrosdst ),

    ( apibh.amtgrosdst - Isnull(apibh.amtgrosdst, 0) - apibh.amtdiscavl ),

    ( ( apibh.amtgrosdst * apibh.exchratehc ) -

    Isnull(apibh.amtgrosdst, 0) * apibh.exchratehc ) - (

    apibh.amtdiscavl * apibh.exchratehc ),

    ( apibh.datebus ),

    apibh.datebus,

    apibh.dateinvc,

    apibh.datedue,

    CASE

    WHEN ( apibh.datedisc ) = 0 THEN NULL

    ELSE dbo.Udf_convert_int_date(apibh.datedisc)

    END,

    apibh.amtdiscavl,

    apibh.codecurn,

    apibh.exchratehc,

    apibh.idtrx,

    Isnull(apibh.amtgrosdst, 0),

    apibh.amttotdist

  • Without knowing much details, It would be all guess work. Please post DDL of the tables, some data and the required output to get better help.

    But seeing your code I think two things I do not understand

    1. AGRREGATION (SUM, MAX etc) with DISTINCT

    2. GROUPING ON COLUMNS WHICH ARE AGGREGATED

    So look into these, as they could be addding more processing than actually needed.

  • Please post table definitions, index definitions and execution plan, as per http://www.sqlservercentral.com/articles/SQLServerCentral/66909/

    You can start fixing the query by removing the nolock, unless you don't mind the query returning incorrect data (and no, I don't just mean dirty reads). See - http://blogs.msdn.com/b/davidlean/archive/2009/04/06/sql-server-nolock-hint-other-poor-ideas.aspx

    Mixing distinct with aggregate... Are those distincts really necessary?

    Several scalar UDFs, if those do data access, that's going to be horridly slow. http://sqlinthewild.co.za/index.php/2009/04/29/functions-io-statistics-and-the-execution-plan/

    Correlated subqueries, not automatically slow, but since you're accessing the same table multiple times that means that SQL will read the table multiple times.

    I suggest a redesign. Start with what you need from the aptcr table, write a single query that gets all the sums, max, etc. Use that as a derived table (subquery in the from clause)

    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
  • To add to what Usman and Gail have recommended, the Udf_convert_int_date is likely a scalar function (according to the way you used it). That's going to make life slower to begin with. Using it in a GROUP BY is only going to be another performance problem because of that and the fact that you can GROUP BY the raw integer date even if it's not in the YYYYMMDD format and still end up with the same result but faster.

    I especially agree with Gails recommendation to Divide'n'Conquer this problem through the use of interim results stored in a Temp Table. Aggregate/manipulate first, then display. It will allow you to avoid several of the sum calculations and most of the repeated queries and their related joins. Don't try to do it all in a single query especially since it seems that you may have some accidental many-to-many joins that require the use of DISTINCT.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Personally I don't think there's anything there that requires distinct, I suspect that distinct is there out of habit, probably the same for the nolocks.

    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

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

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