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


Performance When dropping multiple tables


Performance When dropping multiple tables

Author
Message
Steve Smith-163358
Steve Smith-163358
SSC-Addicted
SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)

Group: General Forum Members
Points: 410 Visits: 301
Hi,

The software we use often creates a lot of temporary tables that need to be deleted from time to time.
Depending on the usage, this can range from hundreds per month to thousands per week.

These temporary tables are all created with names that meet certain conventions, as such, they're quite easy to identify in the database.

Normally, when I've been dropping these tables, I've done it within a cursor.
The cursor identifies the names of the tables in the database, and then the loop process drops each table one at a time.


I'm often conscious of the performance overhead of using a cursor, so have been looking an alternative process for this.
As such, I've tried a new Drop Table command, which comma separates each of the table names and then passes to a single Drop Table command.


declare @DropObjectList varchar(max)

SELECT @DropObjectList = COALESCE(@DropObjectList+',' ,'') + TABLE_NAME
FROM INFORMATION_SCHEMA.TABLES
where TABLE_NAME like 'TEMP[_]TABLE[_]%'

exec ('drop table ' + @DropObjectList)




I've tried doing some basic performance testing on test data, and the results are inconclusive.
It appears to me that the Drop Table command has a higher overhead than looping through the cursor.
Therefore the performance isn't particularly different whether I run through a cursor or not.



Does anyone have any ideas about the fastest way to drop multiple tables whose names meet a certain naming convention, and whether there should be a performance difference whether a cursor is used or not?



Thank you
Steve
Alan.B
Alan.B
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13158 Visits: 8000
Steve Smith-163358 (10/2/2013)
Hi,

The software we use often creates a lot of temporary tables that need to be deleted from time to time.
Depending on the usage, this can range from hundreds per month to thousands per week.


If possible it would be helpful to include a DROP TABLE #<temp_table_name> statement in any stored procs that create them. This may be obvious to you but I see code with temp tables not cleaned up all the time.


...Normally, when I've been dropping these tables, I've done it within a cursor.
The cursor identifies the names of the tables in the database, and then the loop process drops each table one at a time.

I'm often conscious of the performance overhead of using a cursor, so have been looking an alternative process for this.


Cursors are bad for many reasons and should be avoided whenever possible (which is almost always). This article will help you learn to live without cursors, loops, rCTEs and other iterative, non set-based methods for solving this kind of problem.


Does anyone have any ideas about the fastest way to drop multiple tables whose names meet a certain naming convention, and whether there should be a performance difference whether a cursor is used or not?


You could do something like this:


DECLARE @DropObjectList varchar(8000)=''; -- if you can get away with varchar(8000) you will experience better performance

WITH tbls(tbl) AS
( SELECT 'drop table ['+TABLE_NAME+'];' --add brackets for tables with names like "xxx-yyy"
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME like 'TEMP[_]TABLE[_]%'
FOR XML PATH('')
)
SELECT @DropObjectList=tbl
FROM tbls

--PRINT @DropObjectList
EXEC(@DropObjectList)



-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
Steve Smith-163358
Steve Smith-163358
SSC-Addicted
SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)

Group: General Forum Members
Points: 410 Visits: 301
Hi Alan,

Thank you for the reply.
I'll try that code and see how it performs against my other methods.

With regards to the temporary tables within the application, I accidentally used the wrong terminology when posting.
The tables are temporary within the application in as much as they need need to be retained.
However, they aren't actually SQL Server temporary tables (i.e. not # or ## tables)



Again, thank you for the advice.


Steve
Bhuvnesh
Bhuvnesh
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13012 Visits: 4077
Steve Smith-163358 (10/2/2013)
However, they aren't actually SQL Server temporary tables (i.e. not # or ## tables)
Ahhhh... That is actually i wanted to listen.

Here are my 2 cents .
Yes in my last company , we also had same kind of requirement. so what we did , we created another database to store these temp tables (actual physical tables) and then used them. and we also kept them on separate disk. in this way you dont put extra overhead on your sql server (on user db or tempdb) put cleaning/droppping tables will also not impact the peorformance.
So you need separate database.

-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)

Group: General Forum Members
Points: 211207 Visits: 41977
Steve Smith-163358 (10/2/2013)
It appears to me that the Drop Table command has a higher overhead than looping through the cursor.
Therefore the performance isn't particularly different whether I run through a cursor or not.


That's absolutely correct. In fact, this is what cursors were originally designed for... process control. Cursors got a really bad name simply because people took to using them for the wrong things.

Still, I avoid even "process control" cursors like this, especially since the advent of the MAX datatypes in 2005. I've gotten so used to using the methods similar to the code that Alan posted that I'd have to lookup how to write a cursor and use it. :-)

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Steve Smith-163358
Steve Smith-163358
SSC-Addicted
SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)

Group: General Forum Members
Points: 410 Visits: 301
Thank you all very much for your replies, and thank you Jeff for the excellent article that Alan linked to earlier.
I had often read about the merits of set based v's cursors before, but never really grasped the concepts.
More to the point, I didn't realise that half of the code I wrote was set based and half wasn't Smile



Alan, thank you for the code sample.
I've tried using it, but unfortunately I start hitting limits with the size of the data type.
In my test example that I'm using, I have 10,000 tables that I want to delete.

It appears, that due to the number of tables, I can't populate them all into the parameter, even using varchar(max)


With this many tables, I may be stuck with cursors or similar procedures
Bhuvnesh
Bhuvnesh
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13012 Visits: 4077
Steve Smith-163358 (10/3/2013)
With this many tables, I may be stuck with cursors or similar procedures
YOu can do this during Off- peak hours too , may be scehdule a JOB which runs daliy night .

-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
Kurt W. Zimmerman
Kurt W. Zimmerman
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2584 Visits: 1400
If what you are doing occurs every so often, say, once a week, then consider creating a job that runs on the SQL Server Agent off hours. Additionally, if it were up to me, create a procedure that is robust enough to handle the 10k files that needs to be deleted. So if that requires the use of a cursor, so be it. By the way, you can get creative with a WHILE loop if you don't want to render a cursor. Additionally, you can get creative with a WHILE loop to do a batch of deletes over the span of a few evenings or over the span of several hours.

The main thing here is finding a solution that is going to do the job. I really don't think this discussion warrants the discussion of the pros/cons of cursor logic.

Just saying....
Kurt

Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY

http://www.linkedin.com/in/kurtwzimmerman
Steve Smith-163358
Steve Smith-163358
SSC-Addicted
SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)SSC-Addicted (410 reputation)

Group: General Forum Members
Points: 410 Visits: 301
Hi,

thanks again for the replies.
At the moment, the process we have for dropping these tables does indeed run out of hours.
However, I've been tasked with rewriting it for a number of reasons and although it will still run out of hours, I kinda got stuck up on trying to make it as fast / efficient as possible.

while the actual performance impact won't matter because it's out of hours, it'd make me feel good if I could improve the performance.


After reading loads of posts about the performance impact of cursors etc, i wanted to try to drop multiple tables as efficiently as possible without a cursor

Thank you all for your help
Kurt W. Zimmerman
Kurt W. Zimmerman
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2584 Visits: 1400
Steve Smith-163358 (10/3/2013)
Hi,

thanks again for the replies.
At the moment, the process we have for dropping these tables does indeed run out of hours.
However, I've been tasked with rewriting it for a number of reasons and although it will still run out of hours, I kinda got stuck up on trying to make it as fast / efficient as possible.

while the actual performance impact won't matter because it's out of hours, it'd make me feel good if I could improve the performance.


After reading loads of posts about the performance impact of cursors etc, i wanted to try to drop multiple tables as efficiently as possible without a cursor

Thank you all for your help


OK, understood. So what is your efficiency goals? How long is the process running now?

Also, a few years back I was tasked to write a high transaction volume load process. The company I was working for received an update file with several hundred million rows. It was my job to process this file within a 2 hour time window. If I processed the file directly the estimated time period was in the order of 23+ hours, not a solution. So what I did was wrote a process that spawned multiple SQL Server Agent jobs (I think there were 10 separate jobs) to process the update file. By running the 10 jobs concurrently I was able to get the entire process to run in just over 1 hour. Each of the 10 jobs processed a chunk of the incoming file. I was amazed that I didn't run into any kind of deadlocking issues... SQL Server handled the processing just fine.

With that in mind, instead of processing as a single thread, consider "going wide". Consider have multiple procedures that handles a chunk of these files to process at the same time.

Bottom line is you need to define your efficiency goal and sometimes think outside the box for a solution.

Hope this helps.

Kurt

Kurt W. Zimmerman
SR DBA
Lefrak Organization
New York, NY

http://www.linkedin.com/in/kurtwzimmerman
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