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 Tuesday, January 10, 2012 3:46 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 selected the data, it took micro seconds. But, when running an update statement (two columns) it takes too long. The server is going to a 'NOT RESPONDING' state and freezes for about 15 - 20 mins.

Below is the query and details of my research -

UPDATE Table
SET col1='C'
,DATE = '2012-01-10 00:00:00.000'
where NAME in ('A','B')


The table contains of over 2000 records.There is no specific activity on the server, there is a trigger associated with one of the columns which I am trying to update.

Can you get me some inputs on nailing down the cause of the issue. As I am new to be a DBA.

Eshika
Post #1233609
Posted Tuesday, January 10, 2012 4:31 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 1:22 PM
Points: 22,992, Visits: 31,468
Need the ddl (CREATE TABLE script) for the table including the definition for the trigger. If the trigger affects any other tables we will need those also.



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 #1233628
Posted Tuesday, January 10, 2012 4:37 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Yesterday @ 9:44 PM
Points: 21,187, Visits: 14,879
2000 records should take very little time at all to update.

Please provide the trigger definition.




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 #1233631
Posted Tuesday, January 10, 2012 6:50 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
An overview of the trigger - There are two databases DB1-Transactional and DB2-Archive. There are two tables from each database, Tables1 & 2 from DB1 and Tables 3&4 from DB2.

The trigger involves both databases and 4 tables.
As stats column = A from table1 ;
1. updates the date column ;
2. The data will be moved to from TB1 -->Tb3 DB2
3. The corresponding data will be moved to from TB2 -->Tb4 DB2

And all the data from Tb1 & TB2 will be deleted after insert.


Table definition -
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO

CREATE TABLE [Schema1].[Table1](
[ROWID] [bigint] IDENTITY(1,1) NOT NULL,
[LID] [varchar](100) NOT NULL,
[NAME] [varchar](100) NULL,
[TOTALCOUNT] [int] NULL,
[PID] [int] NULL,
[CID] [int] NULL,
[OID] [int] NULL,
[ADATE] [datetime] NULL,
[RDATE] [datetime] NULL,
[CDATE] [date] NULL,
[STAT] [varchar](10) NULL,
[NOTE] [nvarchar](max) NULL,
[REACH] [varchar](4) NULL,
[SA] [varchar](4) NULL,
[RED] [char](1) NULL,
[DK] [varchar](4) NULL,
[DATEINDB] [datetime] NULL,
[MODDATE] [datetime] NULL,
[TID] [varchar](100) NULL,
CONSTRAINT [PK_Table1] PRIMARY KEY NONCLUSTERED
(
[ROWID] ASC,
[LID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO

SET ANSI_PADDING OFF
GO

ALTER TABLE [Schema1].[Table1] ADD CONSTRAINT [DF_Table1_STAT] DEFAULT ('A') FOR [STAT]
GO

ALTER TABLE [Schema1].[Table1] ADD CONSTRAINT [DF_Table1_DATEINDB] DEFAULT (getdate()) FOR [DATEINDB]
GO

Trigger Statement -

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER TRIGGER [Schema1].[Table1_STAT]
ON [Schema1].[Table1]
FOR UPDATE ,INSERT , DELETE
AS
BEGIN
IF NOT UPDATE(MODDATE)
UPDATE [Schema1].[Table1]
SET MODDATE=GETDATE()
WHERE LID IN (SELECT LID FROM inserted WHERE STATUS in ('C','X'))

---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])
SELECT [ROWID] ,[LID],[NAME],[TOTALCOUNT],[PID],[CID],[OID],[ADATE],[RDATE]
[CDATE],[STAT] ,[NOTE] ,[REACH] ,[SA] ,[RED], [DK] , [DATEINDB],[MODDATE],[TID]
FROM inserted
WHERE LID IN (SELECT LID 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)

SELECT 80 columns
FROM [DB1].[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 [DB1].[Schema1].[Table2] WHERE LID IN (SELECT LID FROM inserted WHERE STAT in ('C','X'))
DELETE [DB1].[Schema1].[Table1] WHERE LID IN (SELECT LID FROM inserted WHERE STATUS in ('C','X'))

END



Post #1233674
Posted Tuesday, January 10, 2012 8:17 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 1:22 PM
Points: 22,992, Visits: 31,468
Eshika (1/10/2012)
An overview of the trigger - There are two databases DB1-Transactional and DB2-Archive. There are two tables from each database, Tables1 & 2 from DB1 and Tables 3&4 from DB2.

The trigger involves both databases and 4 tables.
As stats column = A from table1 ;
1. updates the date column ;
2. The data will be moved to from TB1 -->Tb3 DB2
3. The corresponding data will be moved to from TB2 -->Tb4 DB2

And all the data from Tb1 & TB2 will be deleted after insert.


Table definition -
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO
SET ANSI_PADDING ON
GO

CREATE TABLE [Schema1].[Table1](
[ROWID] [bigint] IDENTITY(1,1) NOT NULL,
[LID] [varchar](100) NOT NULL,
[NAME] [varchar](100) NULL,
[TOTALCOUNT] [int] NULL,
[PID] [int] NULL,
[CID] [int] NULL,
[OID] [int] NULL,
[ADATE] [datetime] NULL,
[RDATE] [datetime] NULL,
[CDATE] [date] NULL,
[STAT] [varchar](10) NULL,
[NOTE] [nvarchar](max) NULL,
[REACH] [varchar](4) NULL,
[SA] [varchar](4) NULL,
[RED] [char](1) NULL,
[DK] [varchar](4) NULL,
[DATEINDB] [datetime] NULL,
[MODDATE] [datetime] NULL,
[TID] [varchar](100) NULL,
CONSTRAINT [PK_Table1] PRIMARY KEY NONCLUSTERED
(
[ROWID] ASC,
[LID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO

SET ANSI_PADDING OFF
GO

ALTER TABLE [Schema1].[Table1] ADD CONSTRAINT [DF_Table1_STAT] DEFAULT ('A') FOR [STAT]
GO

ALTER TABLE [Schema1].[Table1] ADD CONSTRAINT [DF_Table1_DATEINDB] DEFAULT (getdate()) FOR [DATEINDB]
GO

Trigger Statement -

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER TRIGGER [Schema1].[Table1_STAT]
ON [Schema1].[Table1]
FOR UPDATE ,INSERT , DELETE
AS
BEGIN
IF NOT UPDATE(MODDATE)
UPDATE [Schema1].[Table1]
SET MODDATE=GETDATE()
WHERE LID IN (SELECT LID FROM inserted WHERE STATUS in ('C','X'))

---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])
SELECT [ROWID] ,[LID],[NAME],[TOTALCOUNT],[PID],[CID],[OID],[ADATE],[RDATE]
[CDATE],[STAT] ,[NOTE] ,[REACH] ,[SA] ,[RED], [DK] , [DATEINDB],[MODDATE],[TID]
FROM inserted
WHERE LID IN (SELECT LID 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)

SELECT 80 columns
FROM [DB1].[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 [DB1].[Schema1].[Table2] WHERE LID IN (SELECT LID FROM inserted WHERE STAT in ('C','X'))
DELETE [DB1].[Schema1].[Table1] WHERE LID IN (SELECT LID FROM inserted WHERE STATUS in ('C','X'))

END






Several things jump out at me:

1) The trigger is defined to be fired on INSERT, UPDATE, or DELETE on the table [Schema1].[Table1].
2) It appears, based on the logic, that perhaps this trigger should only be fired on UPDATE. Question, can data being INSERTed be immediately archived?
3) Do you have recursive triggers enabled on the database. I wouldn't be surprised if this trigger is blocking itself when fired.




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 #1233685
Posted Tuesday, January 10, 2012 8:18 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Yesterday @ 9:44 PM
Points: 21,187, Visits: 14,879
Based on this being related to leads, how large are the tables involved?

Please provide the execution plan too!




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 #1233687
Posted Tuesday, January 10, 2012 8:24 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 1:22 PM
Points: 22,992, Visits: 31,468
SQLRNNR (1/10/2012)
Based on this being related to leads, how large are the tables involved?

Please provide the execution plan too!


Agreed, and it should be the Actual execute plan if possible (but based on my assumption, the estimated may have to do).



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 #1233688
Posted Wednesday, January 11, 2012 1:02 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
In Tables 1&3 there are over 2000 records,tables 2 & 4 there are over 20 million records.
The trigger should be fired on an update, there are no recursive triggers on the tables. I will post the execution plan soon.


I tried to update after disabling the trigger and it was fast. I suspect the size of the tables involved is causing the issue.

Please let me know your thoughts,Thank you for all your responses.
Post #1234321
Posted Wednesday, January 11, 2012 2:03 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Yesterday @ 9:44 PM
Points: 21,187, Visits: 14,879
Eshika (1/11/2012)
In Tables 1&3 there are over 2000 records,tables 2 & 4 there are over 20 million records.
The trigger should be fired on an update, there are no recursive triggers on the tables. I will post the execution plan soon.


I tried to update after disabling the trigger and it was fast. I suspect the size of the tables involved is causing the issue.

Please let me know your thoughts,Thank you for all your responses.


You have the trigger defined for update, insert, delete. Should it only be for update based on what you just said?

Based on the exec plan, your trigger code can likely be optimized so that it will run faster.




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 #1234363
Posted Wednesday, January 11, 2012 2:39 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 1:16 PM
Points: 1,948, Visits: 2,883
On the really large tables, looks like you are using LID, varchar(100), to join / match on them.

Is there an index on LID on the large tables? If so, were you able to check the query plan and verify that SQL will use the index to do those joins / matches?


SQL DBA,SQL Server MVP('07, '08, '09)
"In America, every man is innocent until proven broke!" Brant Parker
Post #1234396
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse