SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Update takes too long and freezes the server


Update takes too long and freezes the server

Author
Message
Eshika
Eshika
SSC-Enthusiastic
SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)SSC-Enthusiastic (130 reputation)

Group: General Forum Members
Points: 130 Visits: 314
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.
SQLRNNR
SQLRNNR
SSC-Dedicated
SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)

Group: General Forum Members
Points: 32210 Visits: 18552
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, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

Lynn Pettis
Lynn Pettis
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39223 Visits: 38529
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



Cool
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)
Lynn Pettis
Lynn Pettis
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39223 Visits: 38529
Just checking to see how things are going with this issue. Any updates?

Cool
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)
Paul White
Paul White
SSCoach
SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)SSCoach (15K reputation)

Group: General Forum Members
Points: 15648 Visits: 11355
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
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
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