Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> RE: Speed up Truncate tables - rebuild index

RE: Speed up Truncate tables - rebuild index

From: Koivu, Lisa <lisa.koivu_at_efairfield.com>
Date: Thu, 16 Aug 2001 09:37:29 -0700
Message-ID: <F001.0036D5D8.20010816092101@fatcity.com>

Ahhh... Thank you.  Pre-coffee over here.

LK

-----Original Message-----

From:   Igor Neyman [SMTP:ineyman_at_perceptron.com]
Sent:   Thursday, August 16, 2001 12:58 PM
To:     Multiple recipients of list ORACLE-L
Subject:        Re: Speed up Truncate tables - rebuild index

Lisa,
 

I think Chris referred to 'alter table ... move', in which case you need to rebuild indexes (ROWIDs changed).
 

Igor Neyman, OCP DBA
Perceptron, Inc.
(734)414-4627
ineyman_at_perceptron.com <mailto:ineyman_at_perceptron.com>
 

Actually Chris if you truncate a table, the indexes on the table are truncated right along with it.  You don't end up with a sparse index, like when you delete many rows.  Try it.  I did (8.1.6)  and was very happy to see this behavior. 

Lisa Koivu
Oracle Database Administrator
Fairfield Resorts, Inc.
954-935-4117

-----Original Message-----

From:   Grabowy, Chris [SMTP:cgrabowy_at_fcg.com]
Sent:   Wednesday, August 15, 2001 5:20 PM
To:     Multiple recipients of list ORACLE-L
Subject:        RE: Speed up Truncate tables

Don't forget to rebuild your indexes...

-----Original Message-----
From: Mercadante, Thomas F [ <mailto:NDATFM_at_labor.state.ny.us>] Sent: Wednesday, August 15, 2001 4:35 PM To: Multiple recipients of list ORACLE-L Subject: RE: Speed up Truncate tables

Cool!  I just tried it - works like a charm!
 

Tom Mercadante
Oracle Certified Professional

-----Original Message-----
From: Riyaj_Shamsudeen_at_i2.com [ <mailto:Riyaj_Shamsudeen_at_i2.com>] Sent: Wednesday, August 15, 2001 4:02 PM To: Multiple recipients of list ORACLE-L Subject: RE: Speed up Truncate tables

Not true, at least in 8i. Using 'alter table move ' you could change the initial extent size..

SQL>alter table test move storage (initial 2M);

Table altered.

Only catch here is that 'move' command doesn't apply to tables having long ,long raw, LOB etc..Initial extent can be changed for the remaining tables..

Thanks
Riyaj "Re-yas" Shamsudeen
Certified Oracle DBA
i2 technologies   www.i2.com

        Christopher Spence <cspence_at_FuelSpot.com>
Sent by: root_at_fatcity.com

08/15/01 02:22 PM
Please respond to ORACLE-L

       
        To:        Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com>
        cc:        
        Subject:        RE: Speed up Truncate tables   

You are correct, unless your using 9i, you cannot alter the initial extent without dropping the table.

"Do not criticize someone until you walked a mile in their shoes, that way when you criticize them, you are a mile a way and have their shoes."

Christopher R. Spence
Oracle DBA
Phone: (978) 322-5744
Fax:    (707) 885-2275

Fuelspot
73 Princeton Street
North, Chelmsford 01863

-----Original Message-----
Sent: Wednesday, August 15, 2001 3:07 PM To: Multiple recipients of list ORACLE-L

Thomas,
are your sure you can change the initial extent?  My senior dba told me once it is not possible; you have to drop and recreate table if there is a need to change Initial extent. I am going to play with it today.

-----Original Message-----
Sent: Wednesday, August 15, 2001 1:27 PM To: Multiple recipients of list ORACLE-L

Chuan,

Kevin is correct.  If your truncate table is taking a *long* time (and the table is not locked by another process), it's because your storage params are incorrect for the amount of data you are holding.

Look at initial and next in comparison with the number of extents (DBA_EXTENTS view) for the table in question, and modify them before you load the data. You can modify the INITIAL extent by issuing an 'alter table allocate extent(size x)' command to grow the INITIAL extent.   You can also modify the NEXT extent by issuing an 'alter table storage (next x)' command to change the NEXT extent.

hope this helps.

Tom Mercadante
Oracle Certified Professional

-----Original Message-----
Sent: Wednesday, August 15, 2001 11:02 AM To: Multiple recipients of list ORACLE-L

I had the same problem when truncating a huge table (24 Mill rows).   It turned out that the reason my table was taking so long was the amount of extents I had on it.  I could look at what was actually happening during a truncate and it had to go and take each individual block and put them back in the available lists.  

Well, after changing the settings on the table to make larger extents (and therefore fewer) the truncates on that table went hundreds of times faster (we had real bad settings on that table before).

You might investigate your storage parms and see just how many extents you do have on that table.

-----Original Message-----
Sent: Wednesday, August 15, 2001 3:10 AM To: Multiple recipients of list ORACLE-L

Hi All,

   Is there any way to speed up the truncating a big table with 12 million
rows?

Basically, I implemented truncating that big table on Production, but it affected the performance much, so I had to stop it in the middle of way. All the rows were truncated but the HWM was not shrunk at all. I want to do it again to get the space back. Is there any way to speed up this process?

Platform: Oracle EE8.0.6 and Solaris 2.7

Thanks a lot in advance.

Chuan

--
Please see the official ORACLE-L FAQ: <http://www.orafaq.com>
--
Author: Chuan Zhang

 INET: chuan_at_asiaonline.net
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from).  You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: <http://www.orafaq.com> -- Author: Kevin Lange
 INET: kgel_at_ppoone.com
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from).  You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: <http://www.orafaq.com> -- Author: Mercadante, Thomas F
 INET: NDATFM_at_labor.state.ny.us
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from).  You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: <http://www.orafaq.com> -- Author:
 INET: lhoska_at_calibresys.com
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from).  You may also send the HELP command for other information (like subscribing). -- Please see the official ORACLE-L FAQ: <http://www.orafaq.com> -- Author: Christopher Spence
 INET: cspence_at_FuelSpot.com
Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051 San Diego, California        -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from).  You may also send the HELP command for other information (like subscribing).
Received on Thu Aug 16 2001 - 11:37:29 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US