Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Query running for morethan 2Hours 30 min


Query running for morethan 2Hours 30 min

Author
Message
Gangadhara MS
Gangadhara MS
SSC-Enthusiastic
SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)

Group: General Forum Members
Points: 137 Visits: 840
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
            Wink
            
         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
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16539 Visits: 16992
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Gangadhara MS
Gangadhara MS
SSC-Enthusiastic
SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)

Group: General Forum Members
Points: 137 Visits: 840
PLAN ATTACHED.

sp_helpindex 'DML.ExceptionstrackingTable'

IX_DMLIsDeletedFlagganga   nonclustered located on PRIMARY   DMLIsDeletedFlag
IX_gangadded   nonclustered located on PRIMARY   DMLIsDeletedFlag, OriginalSubscriptionKey
NCIX_ActivationModel   nonclustered located on PRIMARY   ActivationModel, ExceptionType
NCIX_BatchID   nonclustered located on PRIMARY   BatchID
NCIX_EntitlementID   nonclustered located on PRIMARY   EntitlementID
NCIX_ExceptionsTrackingTable_CalcProductKeyID   nonclustered located on PRIMARY   CalcProductKeyID
NCIX_GrpIDChannelIDSeqNo   nonclustered located on PRIMARY   GrpID, ChannelID, SeqNo
NCIX_IsDeletedFlag   nonclustered located on PRIMARY   DMLIsDeletedFlag
NCIX_MachineKey   nonclustered located on PRIMARY   MachineKey
NCIX_PartnerEntitlementID   nonclustered located on PRIMARY   PartnerEntitlementID
NCIX_RUNID   nonclustered located on PRIMARY   RunID
PK_ExceptionsTracking   clustered, unique, primary key located on PRIMARY   ActID, ExceptionType
Attachments
exec.plan.sqlplan (16 views, 103.00 KB)
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8484 Visits: 18082
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'
            Wink
         AND ActivationModel = 'Subscription'
         AND Machine.MachineKey = ExceptionsTrackingTable.ActID
      Wink
   AND NOT EXISTS (
      SELECT 1
      FROM DML.ExtOLSEntitlement Entitlement
      WHERE Entitlement.EntitlementId = Machine.EntitlementId
      Wink



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


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
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8484 Visits: 18082
Gangadhara MS (5/7/2014)
PLAN ATTACHED.

sp_helpindex 'DML.ExceptionstrackingTable'

IX_DMLIsDeletedFlagganga   nonclustered located on PRIMARY   DMLIsDeletedFlag
IX_gangadded   nonclustered located on PRIMARY   DMLIsDeletedFlag, OriginalSubscriptionKey
NCIX_ActivationModel   nonclustered located on PRIMARY   ActivationModel, ExceptionType
NCIX_BatchID   nonclustered located on PRIMARY   BatchID
NCIX_EntitlementID   nonclustered located on PRIMARY   EntitlementID
NCIX_ExceptionsTrackingTable_CalcProductKeyID   nonclustered located on PRIMARY   CalcProductKeyID
NCIX_GrpIDChannelIDSeqNo   nonclustered located on PRIMARY   GrpID, ChannelID, SeqNo
NCIX_IsDeletedFlag   nonclustered located on PRIMARY   DMLIsDeletedFlag
NCIX_MachineKey   nonclustered located on PRIMARY   MachineKey
NCIX_PartnerEntitlementID   nonclustered located on PRIMARY   PartnerEntitlementID
NCIX_RUNID   nonclustered located on PRIMARY   RunID
PK_ExceptionsTracking   clustered, unique, primary key located on PRIMARY   ActID, 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
MMartin1
MMartin1
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1077 Visits: 2009
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?

----------------------------------------------------
How to post forum questions to get the best help
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search