Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: using temp tables for staging databases?
Unless you typo'd, there are some serious problems here...
Setting PCTFREE to 99 is not likely to "pack in the blocks". Rather the opposite; you are instead leaving blocks 99% empty. Quite a bit of wasted I/O in performing a FULL table scan here... :-)
Anyway, it is not a good idea to have PCTFREE and PCTUSED sum to a value greater than 70 or 80 or so, just as a rule of thumb. Having them sum to a value near 100 ensures that each insert, delete, or even update will potentially cause the block to be removed or reinserted to one of the segment's free list. Think about it: the width of a single row crossing the boundary from "off the free list" to "on the free list". Better to leave a bit of a "no man's land" between the two values. The default settings of PCTFREE=10 and PCTUSED=40 are one of the few default settings that need little manipulation for most situations.
on 10/20/03 7:34 AM, rgaffuri_at_cox.net at rgaffuri_at_cox.net wrote:
> we drop and recreate the temp tables every night. We also use PCTFREE PCTUSED > at 99 and 1 to pack in the blocks and we use very small extent sizes. then we > analyze with an estimate size of 20 percent which is quite fast. > > All of them are used for full table scans and do not have indexes. Ive found > that a 'create table as' is MUCH faster than inserting into global temporary > tables when you do not have to worry about latch contention(ie 1-3 users > logged in at a time). > > anyone else notice this? Seems to go against conventional wisdom which says > never use them. So I want to make sure Im not missing something.
>>> This is for non-transactional data load instances. The guys here sware that >>> by >>> using smaller temporary tables(not global temp tables) they can increase the >>> speed of the data loads. >>> >>> Not worried about latch contention because its just for bulk loads. I know >>> this bad in transactional instances. Has anyone used these in >>> non-transactional data load instances?
-- Please see the official ORACLE-L FAQ: http://www.orafaq.net -- Author: Tim Gorman INET: tim_at_sagelogix.com Fat City Network Services -- 858-538-5051 http://www.fatcity.com San Diego, California -- Mailing list and web hosting services --------------------------------------------------------------------- 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 Tue Oct 21 2003 - 00:09:26 CDT