RE: INSERT versus CTAS

  • From: Riyaj Shamsudeen <rshamsud@xxxxxxxxxxxx>
  • To: gorbyx@xxxxxxxxx, "'ORACLE-L'" <oracle-l@xxxxxxxxxxxxx>
  • Date: Sat, 11 Dec 2004 11:55:26 -0600

Hi Gorbachev
You said :
        I want to change INSERT to CTAS, but it requires some efforts to
amend the script. I assume that CTAS would be > more performant for IOT
since it will create index as temporary segment in table's tablespace
and then just amend dictionary (object definition + hwm). So I expect to
eleminate UNDO generation, reduce temporary space requirements, reduce
redo, and.... well, boost performance.
-----
Yes. CTAS is far better for IOTs then Insert with append hint..In fact,
I just converted a heap partitioned table (4 billion rows or so) to
compressed partitioned IOT using this method. Worked great. Idea is to
create another IOT table exactly same as original table partition and
exchange partitions.
-- Create a table from the old partition
CREATE TABLE ilp_seg_1
(
  ITEM_SET_ID   ,
  LOCATION_ID   ,
  PERIOD_ID     ,
  SEGMENT_TYPE  ,
  RCPT_AMT      ,
  RCPT_UNITS    ,
  SLS_AMT       ,
  SLS_UNITS     ,
constraint ilp_seg_1_pk
primary key (item_set_id, location_id, period_id, segment_type)
)
ORGANIZATION INDEX
COMPRESS 2
NOPARALLEL
tablespace ilp_data_01
nologging
as select /*+ parallel (ilp 4) */ * from
ab4p.item_location_periods_tbl_dec10 ilp
 where segment_type=1
/

-- Exchange it..
-- With validation clause is to avoid a bug in 8i. 'Without validation'
clause is using an highly inefficient SQL.

alter table item_location_periods_tbl
 exchange partition   ITEM_LOC_PER_SEG_1 with table  ilp_seg_1
 including indexes
 with validation
/

8.1.7.4 64 bit +  one-off patch for compressed index bug, in Sun 2.8

Thanks
Riyaj "Re-yas" Shamsudeen
Certified Oracle DBA


-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx] On Behalf Of Alexander Gorbachev
Sent: Saturday, December 11, 2004 9:41 AM
To: ORACLE-L
Subject: INSERT versus CTAS


Hi,

What are the differencies between "create ... table as select" and
"create table" + "insert /*+ parallel(...) append(...) */ into" from
performance point of view? I am interested in various tables:
- non-partitioned
- partitioned
- non pratitioned IOT
- partitioned IOT

Currently, I use create + insert with parallel append hints. It works
reasonable fast for us - we are able to fill 100+ Gb of data within 1,5
hour. However, inserting in partitioned IOT's is quite different. There
are few problems:
- slow
- append doesn't work (and, consequently, parallel).
- lot's of redo (coz no append).
- lot's of undo (I guess because no append as well, since with append
you need only revert HWM) and, consequently, ora-1555.
- lot's of temporary space required.

We are able to overcome some problems iterating through each partition,
but it's not a clean solution and performance is still far from what we
target.

I want to change INSERT to CTAS, but it requires some efforts to amend
the script. I assume that CTAS would be more performant for IOT since it
will create index as temporary segment in table's tablespace and then
just amend dictionary (object definition + hwm). So I expect to
eleminate UNDO generation, reduce temporary space requirements, reduce
redo, and.... well, boost performance.

Any comments/links are appreciated.

It's 9.2.0.5 on 64 bit HP-UX.

Thanks in advance.
Alex

-- 
Best regards,
Alex Gorbachev
--
//www.freelists.org/webpage/oracle-l



-- Attached file included as plaintext by Ecartis --
-- Desc: Signature

The information transmitted is intended only for the person or entity to
which it is addressed and may contain confidential and/or privileged
material.  If the reader of this message is not the intended recipient,
you are hereby notified that your access is unauthorized, and any review,
dissemination, distribution or copying of this message including any
attachments is strictly prohibited.   If you are not the intended
recipient, please contact the sender and delete the material from any
computer.


--
//www.freelists.org/webpage/oracle-l

Other related posts: