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


Delete


Delete

Author
Message
ibidapo22
ibidapo22
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 67
I wrote query to delete some records in one of the table in my database.
I set up job to run this query.
The query is as below:

DELETE I
FROM tbItem I (nolock)
INNER JOIN tbProductionOrder PO (nolock)
ON I.POID = PO.POID
WHERE PODescription LIKE '%00000%'

This job has ran successfully in the past, but now it start hanging my system to extent that they cannot work in the factory, what are the possible causes?
GilaMonster
GilaMonster
SSC Guru
SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)

Group: General Forum Members
Points: 116957 Visits: 45530
how many rows is that delete likely to affect?
What indexes do you have on the 2 tables?

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


UDBNT
UDBNT
SSC-Addicted
SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)

Group: General Forum Members
Points: 463 Visits: 208
Not sure on the validity of (nolock) on a table where you are deleting data?

That aside, you mentioned this has worked in the past, but not so well now.

What you don't state is other contributing factors like
* Volume of data involve on both the related tables
* Is there an RI link and has that any supportive indexing to help the query.
* What sort of number of deletes are you expecting, ie When originally run a few rows to be deleted would not have the same impact as say several thousand.

As with a lot of the forum items on this site (I know because I have asked questions as well), it works a lot better if you can give as much relevant details on the issue as possible.

Cheers.
ibidapo22
ibidapo22
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 67
DELETE I
FROM tbItem I (nolock)
INNER JOIN tbProductionOrder PO (nolock)
ON I.POID = PO.POID
WHERE PODescription LIKE '%00000%'

This will delete about 11000000 records
Once again this has been successfully severally
GilaMonster
GilaMonster
SSC Guru
SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)

Group: General Forum Members
Points: 116957 Visits: 45530
Index definitions?
Has the total number of rows in the table changed since this worked properly?
Are your indexes fragmented? Are the statistics out of date?

I'm not asking just to be a pain. I'm asking because I want as clear a picture of the problem as possible.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


GilaMonster
GilaMonster
SSC Guru
SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)SSC Guru (116K reputation)

Group: General Forum Members
Points: 116957 Visits: 45530
UDBNT (6/11/2008)
Not sure on the validity of (nolock) on a table where you are deleting data?


The hint will be ignored. Deletes have to lock exclusivly, lock hints or no lock hints.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


UDBNT
UDBNT
SSC-Addicted
SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)SSC-Addicted (463 reputation)

Group: General Forum Members
Points: 463 Visits: 208
Fair enough, it was just that I seem to remember some reference to (nolock) dealing with potentially non-commited data and the obvious impacts of that might not be that desirable.

Seems like we are both asking for more detail/history from the originator.
Delete of 11 million rows doesn't sound like a daily task to me, but I might be wrong!!
ibidapo22
ibidapo22
Grasshopper
Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)Grasshopper (21 reputation)

Group: General Forum Members
Points: 21 Visits: 67
The 11 Million is a standard number so it does not vary
I also run DBCC DBREINDEX on the table earlier
So question of defragmentation should not come up
MANU-J.
MANU-J.
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3828 Visits: 8766
It would be helpful if you mention the index structure on both the tables involved in delete operation.

Manu
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)

Group: General Forum Members
Points: 51868 Visits: 38684
I'd write it more like this:


DELETE FROM
dbo.tbItem
FROM
dbo.tbItem I
INNER JOIN dbo.tbProductionOrder PO
ON (I.POID = PO.POID)
WHERE
PO.PODescription LIKE '%00000%'



You could also encolse this is a while loop and delete records in smaller batches.


declare @recordstodelete int,
@recordsdeleted int;
set @recordstodelete = 5000;

while (@recordsdeleted is null)
or (@recordsdeleted <> 0)
begin -- while

DELETE TOP (@recordstodelete) FROM
dbo.tbItem
FROM
dbo.tbItem I
INNER JOIN dbo.tbProductionOrder PO
ON (I.POID = PO.POID)
WHERE
PO.PODescription LIKE '%00000%'

set @recordsdeleted = @@rowcount

-- BACKUP LOG ... -- a transaction log backup could be coded here to manage t-log size

end -- while




Cool

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)
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