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

Why is this code deleting only 1 row at a time instead of using the condition and deleting many rows? Expand / Collapse
Author
Message
Posted Friday, July 18, 2014 3:24 PM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Sunday, December 14, 2014 9:18 AM
Points: 175, Visits: 346
/****** Object: StoredProcedure [dbo].[dbo.ServiceLog] Script Date: 07/18/2014 14:30:59 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER proc [dbo].[ServiceLogPurge]

-- Purge records dbo.ServiceLog older than 3 months:
-- Purge records in small portions to avoid locking production tables
-- for a long time. The process takes longer, but can co-exist with
-- normal usage of the tables.

@KeepDays int = 90 -- Purge records older than midnight @KeepDays days ago

as
set nocount on

declare @ServiceLogID int,
@Created datetime,
@Error int,
@Message varchar(8000)

-- Purge records that qualify for purging:

declare QualifyingServiceLogID cursor
for select ServiceLogID
from ServiceLog (nolock)
where Created < convert( char(10), dateadd( day, -@KeepDays, getdate() ), 121 )
order by ServiceLogID

open QualifyingServiceLogID

fetch next from QualifyingServiceLogID into @ServiceLogID
if exists ( select 1 from ServiceLog where ServiceLogID = @ServiceLogID ) begin
begin try
delete ServiceLog
where ServiceLogID = @ServiceLogID
end try
begin catch
select @Error = error_number(),
@Message = 'failed to delete ServiceLog for cleanup after the last failed execution. Error ' +
convert( varchar, error_number() ) + ': ' + error_message()
goto Failed
end catch

fetch next from QualifyingServiceLogID into @ServiceLogID
end

-- Error-handling:
Failed:

raiserror( 'ServiceLog has %s', 11, 1, @Message )


close QualifyingServiceLogID
deallocate QualifyingServiceLogID


*** Getting this error below when executing the code ***

Msg 102, Level 15, State 1, Procedure ServiceLogPurge, Line 45
Incorrect syntax near 'Failed:'.



Post #1594251
Posted Friday, July 18, 2014 3:51 PM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 12:55 PM
Points: 4,046, Visits: 9,200
Because the cursor is set to delete one ServiceLogID at a time.
Even after reading the comments, I'm not sure that it's a good solution, but I don't know the entire story.



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 #1594254
Posted Friday, July 18, 2014 3:54 PM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: Today @ 3:20 PM
Points: 18,064, Visits: 16,099
I don't know why you would cursor through to delete a Log one record at a time.

Why not change it to a set-based approach?




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


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Post #1594255
Posted Friday, July 18, 2014 3:55 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Monday, December 15, 2014 2:26 PM
Points: 5,466, Visits: 7,647
delete ServiceLog
where ServiceLogID = @ServiceLogID

That's a single row removal, not a range. The question is why they chose this technique. It's typically a poor method unless you've got significant concurrency concerns.



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1594256
Posted Friday, July 18, 2014 4:02 PM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Sunday, December 14, 2014 9:18 AM
Points: 175, Visits: 346
You guys are all right, this is madness I've created here. I'm trying to avoid blocking since there are rows that will be inserting in table frequently. Can one of provide some examples to avoid blocking but at the same time delete data from this table only keeping 3 months? Set based sounds like a good approach. Thanks all.


Post #1594257
Posted Friday, July 18, 2014 4:20 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Monday, December 15, 2014 2:26 PM
Points: 5,466, Visits: 7,647
davidsalazar01 (7/18/2014)
You guys are all right, this is madness I've created here. I'm trying to avoid blocking since there are rows that will be inserting in table frequently. Can one of provide some examples to avoid blocking but at the same time delete data from this table only keeping 3 months? Set based sounds like a good approach. Thanks all.



declare QualifyingServiceLogID cursor
for select ServiceLogID
from ServiceLog (nolock)
where Created < convert( char(10), dateadd( day, -@KeepDays, getdate() ), 121 )
order by ServiceLogID


Is Created actually a text field? Is it indexed properly? Can we see the schema on ServiceLog?



- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1594260
Posted Friday, July 18, 2014 4:31 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 5:19 PM
Points: 20,859, Visits: 32,882
Assuming this process is run once a day and you want current day plus last 90 days, give this a try:


declare @BatchSize int = 10000,
@CurrentDate date = getdate(),
@KeepDays int = 90;

while @BatchSize > 0
begin
delete top (@BatchSize)
from dbo.ServiceLog
where
Created < dateadd(day,-(@KeepDays),@CurrentDate);

set @BatchSize = @@ROWCOUNT;
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 #1594263
Posted Friday, July 18, 2014 4:35 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Monday, December 15, 2014 2:26 PM
Points: 5,466, Visits: 7,647
Lynn, curiousity, why wouldn't you set that to 4,500 rows instead of 10k to avoid table lock escalation?


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Post #1594266
Posted Friday, July 18, 2014 4:57 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 5:19 PM
Points: 20,859, Visits: 32,882
Evil Kraig F (7/18/2014)
Lynn, curiousity, why wouldn't you set that to 4,500 rows instead of 10k to avoid table lock escalation?


That is really just a suggestion. The OP can set it to whatever value desired. I picked 10,000 because it was a number. It also depends on how long it takes to delete a batch. I could also have put a WAITFOR statement in the while loop to slow down the deletes some more to allow other processes to access the table as well. In addition, I have no idea how many rows of data there are in the table nor how many are added a day. Plus, if run during a period of low activity it may not even matter if there is a table lock or not.

So, setting it to a specific value really is a "it depends" kind of thing.



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 #1594268
Posted Friday, July 18, 2014 6:39 PM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Sunday, December 14, 2014 9:18 AM
Points: 175, Visits: 346
All comments are good pointers and the sample code provided really helps a lot. I appreciate your help.


Post #1594280
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse