Query running for morethan 2Hours 30 min

  • Hi

    This query takes morethan a 2 Hour to complete and also attached the exec plan

    The DML.ExceptionsTrackingTable is having morethan 125 Million records and this query runs for almost close to 3 Hours.

    Please help me what and all i can look into it.

    IF OBJECT_ID('tempdb..#MissingPAIntelorCP') IS NOT NULL

    DROP TABLE #MissingPAIntelorCP

    CREATE TABLE #MissingPAIntelorCP(

    ActID NVARCHAR(50) PRIMARY KEY NOT NULL

    )

    INSERT INTO #MissingPAIntelorCP

    SELECT DISTINCT ActID

    FROM DML.ExceptionsTrackingTable (NOLOCK)

    WHERE ExceptionType IN ('No PAIntel Activations and CP Data' ,'No PAIntel Activations')

    And ActivationModel = 'Subscription'

    SELECT 'OREF' AppCode

    ,OLSEntitlement.LiveIDEncryptedKey

    ,'Subscription' ActivationModel

    ,GETDATE() DMLUpdatedTimestamp

    ,CAST(Machine.MachineKey AS VARCHAR(50)) COLLATE Latin1_General_CS_AS ActID

    ,Machine.MachineKey

    ,Machine.MachineType

    ,OLSEntitlement.PartnerEntitlementId

    ,N'No data from PAIntel Activations AND CP,but OLS has data' ExceptionReason

    ,N'No PAIntel Activations and CP Data' ExceptionType

    ,0 AS DMLIsDeletedFlag

    -- 1696399 (1710621).Get the EntitlementID from extract table instead of exceptions,this takes care to poplate the accumulate table with new EntitlementID

    -- even though the first exception record was in old format.Also this will help dedupe script to remove the entitlementid in case of mixed formats.

    ,Machine.EntitlementId AS EntitlementID

    FROM DML.ExtOLSMachine Machine

    JOIN DML.ExceptionsTrackingTable OLSEntitlement

    ON OLSEntitlement.EntitlementId = Machine.EntitlementId

    LEFT JOIN DML.ExtOLSEntitlement Entitlement

    ON Entitlement.EntitlementId = Machine.EntitlementId

    LEFT JOIN #MissingPAIntelorCP MissingPAIntelorCP

    ON CAST(Machine.MachineKey AS VARCHAR(50)) COLLATE Latin1_General_CS_AS = MissingPAIntelorCP.ActID

    WHERE Entitlement.EntitlementId IS NULL

    AND MissingPAIntelorCP.ActID IS NULL

    AND OLSEntitlement.EntitlementId IS NOT NULL

    And OLSEntitlement.DMLIsDeletedFlag = 0

  • There is no execution plan attached. It would also be helpful if you could include table and index definitions.

    Why are you using NOLOCK? Is missing and/or duplicate data acceptable? This hint is deprecated and so is the way you are using it. If you use table hints you must include the WITH keyword. In general table hints should be avoided unless there is a valid reason.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • PLAN ATTACHED.

    sp_helpindex 'DML.ExceptionstrackingTable'

    IX_DMLIsDeletedFlagganganonclustered located on PRIMARYDMLIsDeletedFlag

    IX_gangaddednonclustered located on PRIMARYDMLIsDeletedFlag, OriginalSubscriptionKey

    NCIX_ActivationModelnonclustered located on PRIMARYActivationModel, ExceptionType

    NCIX_BatchIDnonclustered located on PRIMARYBatchID

    NCIX_EntitlementIDnonclustered located on PRIMARYEntitlementID

    NCIX_ExceptionsTrackingTable_CalcProductKeyIDnonclustered located on PRIMARYCalcProductKeyID

    NCIX_GrpIDChannelIDSeqNononclustered located on PRIMARYGrpID, ChannelID, SeqNo

    NCIX_IsDeletedFlagnonclustered located on PRIMARYDMLIsDeletedFlag

    NCIX_MachineKeynonclustered located on PRIMARYMachineKey

    NCIX_PartnerEntitlementIDnonclustered located on PRIMARYPartnerEntitlementID

    NCIX_RUNIDnonclustered located on PRIMARYRunID

    PK_ExceptionsTrackingclustered, unique, primary key located on PRIMARYActID, ExceptionType

  • I agree on everything that Sean has said.

    I guess from my part is that your DISTINCT on 125 million rows is generating problems. This might help, and proper indexing should help even more.

    SELECT 'OREF' AppCode

    ,OLSEntitlement.LiveIDEncryptedKey

    ,'Subscription' ActivationModel

    ,GETDATE() DMLUpdatedTimestamp

    ,CAST(Machine.MachineKey AS VARCHAR(50)) COLLATE Latin1_General_CS_AS ActID

    ,Machine.MachineKey

    ,Machine.MachineType

    ,OLSEntitlement.PartnerEntitlementId

    ,N'No data from PAIntel Activations AND CP,but OLS has data' ExceptionReason

    ,N'No PAIntel Activations and CP Data' ExceptionType

    ,0 AS DMLIsDeletedFlag

    -- 1696399 (1710621).Get the EntitlementID from extract table instead of exceptions,this takes care to poplate the accumulate table with new EntitlementID

    -- even though the first exception record was in old format.Also this will help dedupe script to remove the entitlementid in case of mixed formats.

    ,Machine.EntitlementId AS EntitlementID

    FROM DML.ExtOLSMachine Machine

    JOIN DML.ExceptionsTrackingTable OLSEntitlement ON OLSEntitlement.EntitlementId = Machine.EntitlementId

    WHERE OLSEntitlement.DMLIsDeletedFlag = 0

    AND NOT EXISTS (

    SELECT 1

    FROM DML.ExceptionsTrackingTable

    WHERE ExceptionType IN (

    'No PAIntel Activations and CP Data'

    ,'No PAIntel Activations'

    )

    AND ActivationModel = 'Subscription'

    AND Machine.MachineKey = ExceptionsTrackingTable.ActID

    )

    AND NOT EXISTS (

    SELECT 1

    FROM DML.ExtOLSEntitlement Entitlement

    WHERE Entitlement.EntitlementId = Machine.EntitlementId

    )

    For better suggestions, include the execution plan and DDL for tables and indexes.

    EDIT: Corrected errors in the code posted.

    Reference: Left outer join vs NOT EXISTS[/url]

    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
  • Gangadhara MS (5/7/2014)


    PLAN ATTACHED.

    sp_helpindex 'DML.ExceptionstrackingTable'

    IX_DMLIsDeletedFlagganganonclustered located on PRIMARYDMLIsDeletedFlag

    IX_gangaddednonclustered located on PRIMARYDMLIsDeletedFlag, OriginalSubscriptionKey

    NCIX_ActivationModelnonclustered located on PRIMARYActivationModel, ExceptionType

    NCIX_BatchIDnonclustered located on PRIMARYBatchID

    NCIX_EntitlementIDnonclustered located on PRIMARYEntitlementID

    NCIX_ExceptionsTrackingTable_CalcProductKeyIDnonclustered located on PRIMARYCalcProductKeyID

    NCIX_GrpIDChannelIDSeqNononclustered located on PRIMARYGrpID, ChannelID, SeqNo

    NCIX_IsDeletedFlagnonclustered located on PRIMARYDMLIsDeletedFlag

    NCIX_MachineKeynonclustered located on PRIMARYMachineKey

    NCIX_PartnerEntitlementIDnonclustered located on PRIMARYPartnerEntitlementID

    NCIX_RUNIDnonclustered located on PRIMARYRunID

    PK_ExceptionsTrackingclustered, unique, primary key located on PRIMARYActID, ExceptionType

    Do you realize that you have several repeated indexes? IX_DMLIsDeletedFlagganga and NCIX_IsDeletedFlag are useless if you have IX_gangadded.

    You didn't include the actual execution plan or table definitions.

    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
  • One thing that slows things down is casting in the where clause. I see this in query 2.

    plus I also see in the WHERE clause -->

    Entitlement.EntitlementId IS NULL where this is a right table. So you are not doing the filtering in the join. So that means these rows will be removed after you processed the join. This is a different result set than if you put the filter in the join. You do this on at least a couple of other right tables so I recommend you revisit the business requirement here. If you dont want these rows from the left or right tables, better to not use the left join and an inner join instead. That will save you some processing of having a result set only to delete from it again. Does this makes sense?

    ----------------------------------------------------

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

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