Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Query running for morethan 2Hours 30 min Expand / Collapse
Author
Message
Posted Wednesday, May 7, 2014 3:35 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, December 1, 2014 12:49 PM
Points: 132, Visits: 822
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
Post #1568717
Posted Wednesday, May 7, 2014 3:43 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 8:12 AM
Points: 13,326, Visits: 12,814
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)
Post #1568718
Posted Wednesday, May 7, 2014 3:52 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Monday, December 1, 2014 12:49 PM
Points: 132, Visits: 822
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


  Post Attachments 
exec.plan.sqlplan (16 views, 103.21 KB)
Post #1568722
Posted Wednesday, May 7, 2014 3:53 PM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 8:58 AM
Points: 4,043, Visits: 9,198
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



Luis C.
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?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1568724
Posted Wednesday, May 7, 2014 4:24 PM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 8:58 AM
Points: 4,043, Visits: 9,198
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.
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?

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1568729
Posted Wednesday, June 11, 2014 5:28 PM


SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Yesterday @ 5:13 PM
Points: 456, Visits: 1,060

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?
Post #1579857
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse