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 ««12

Update takes too long and freezes the server Expand / Collapse
Author
Message
Posted Wednesday, January 11, 2012 6:14 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Saturday, May 24, 2014 3:11 PM
Points: 72, Visits: 309
I have a clustered and non-clustered index on LID in tables 1&3 but not in 2 & 4. The execution plan for the update statement includes execution plan for the trigger. The execution plan states there are missing indexes- which are already existing. I have real hard time inserting images in the post.




Post #1234496
Posted Wednesday, January 11, 2012 7:09 PM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 5:06 PM
Points: 17,728, Visits: 15,592
Read this link and then post the execution plan

http://www.sqlservercentral.com/articles/SQLServerCentral/66909/


The missing indexes being recommend by the execution plan are probably not covering indexes but we can't tell that if we can't see the plan.

We would also need to see some scripts for the tables involved.




Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #1234505
Posted Wednesday, January 11, 2012 11:23 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 5:02 PM
Points: 20,705, Visits: 32,354
Try the following trigger in a test environment. You will need to update it as you didn't provide all the information needed (no definition for the second table (80 columns)). Also, be sure to note the comments where I modified or added code.

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER TRIGGER [Schema1].[Table1_STAT]
ON [Schema1].[Table1]
FOR UPDATE -- , INSERT, DELETE <- If you don't want this fired on INSERT or DELETE, don't include them
AS
BEGIN
-- IF NOT UPDATE(MODDATE)
-- UPDATE [Schema1].[Table1]
-- SET MODDATE = GETDATE() -- why do this when you are going to delete immediately anyway
-- WHERE LID IN (SELECT LID FROM inserted WHERE STATUS in ('C','X'))

-- declare table variables to hold the values being archived
declare @archive_table1 table (
--columns for table 1
)

declare @archive_table2 table (
--columns for table 2
)


---Insert the C or X lead sheet to arch
INSERT INTO [DB2].[dbo].[ArchTable2](
[ROWID] ,
[LID],
[NAME],
[TOTALCOUNT],
[PID],
[CID],
[OID],
[ADATE],
[RDATE],
[CDATE],
[STAT] ,
[NOTE] ,
[REACH] ,
[SA] ,
[RED],
[DK] ,
[DATEINDB],
[MODDATE],
[TID]
)
output ( -- Output the rows to a table variable that are being archived
[ROWID] ,
[LID],
[NAME],
[TOTALCOUNT],
[PID],
[CID],
[OID],
[ADATE],
[RDATE],
[CDATE],
[STAT] ,
[NOTE] ,
[REACH] ,
[SA] ,
[RED],
[DK] ,
[DATEINDB],
[MODDATE],
[TID]
) into @archive_table1
SELECT
[ROWID] ,
[LID],
[NAME],
[TOTALCOUNT],
[PID],
[CID],
[OID],
[ADATE],
[RDATE]
[CDATE],
[STAT] ,
[NOTE] ,
[REACH] ,
[SA] ,
[RED],
[DK] ,
[DATEINDB],
GETDATE(), -- [MODDATE], <- Put the datetime here
[TID]
FROM
inserted
WHERE
STAT in ('C','X')

-- Insert the closed or disabled lead sheet associated leads to arch
INSERT INTO [DB2].[dbo].[ARCHTable3]
(80 Columns)
output ( -- Output the rows to a table variable that are being archived
80 columns
) into @archive_table2
SELECT 80 columns
FROM [Schema1].[Table2] A INNER JOIN inserted I
ON A.[LID] = I.LID
WHERE I.STAT in ('C','X')

-- Delete all the closed or disabled lead sheets and leads after archiving

DELETE FROM
[Schema1].[Table2]
FROM
[Schema1].[Table2] t2
inner join @archive_table2 at2
on (t2.LID = at2.LID)

DELETE FROM
[Schema1].[Table1]
FROM
[Schema1].[Table1] t1
inner join @archive_table1 at1
on (t1.LID = at1.LID)

END




Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1234532
Posted Saturday, January 14, 2012 11:05 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 5:02 PM
Points: 20,705, Visits: 32,354
Just checking to see how things are going with this issue. Any updates?



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1236175
Posted Saturday, January 14, 2012 11:24 AM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: 2 days ago @ 10:07 PM
Points: 9,926, Visits: 11,183
These problems are usually caused by the optimizer choosing a nested loops join for the trigger statements that join to the inserted or deleted pseudo-tables. This would be obvious from an execution plan with runtime statistics (trigger execution plans do not appear when only an estimated plan is requested). The solution is almost always to add OPTION (HASH JOIN, MERGE JOIN) to the problem statements in the trigger. This will prevent the nested loops join algorithm being considered by the optimizer.



Paul White
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #1236180
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse