Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Question about Append hint in Insert
But if the table has an index, and even if you use the NOLOGGING hint (and
create the table and index NOLOGGING too)
it appears that you still generate redo when maintaining the index.
The only way I have found to avoid redo on the index is to populate the
table and then build the index NOLOGGING.
(am I missing anything?)
Attached is a simple test script and my output on 9.2.0.5.
-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org]On Behalf Of Jonathan Lewis
Sent: 18 June 2004 22:33
To: oracle-l_at_freelists.org
Subject: Re: Question about Append hint in Insert
Mark,
APPEND stops table UNDO, not table REDO. That point often gets hidden because the hint is used so often in conjunction with nologging tables.
Otherwise your comments are correct - the benefit applies only to the table segment, and you get the exclusive table lock.
There is some potential for benefit on the indexes because the index entries are per-sorted before inserting, and there is an optimization that reduces undo and redo if multiple rows goes into a single leaf block.
There is some downside on the table because the HWM is bumped for the append, so you could leave a trail of empty space behind you as you do lots of appends - but at 1,000 rows per insert, the percentage waste of space is likely to be small.
Regards
Jonathan Lewis
http://www.jlcomp.demon.co.uk/faq/ind_faq.html The Co-operative Oracle Users' FAQ
http://www.jlcomp.demon.co.uk/seminar.html Optimising Oracle Seminar - schedule updated May 1st
Harvinder,
1.) Should be no real disadvantage, other than an exclusive lock on the
table. More on that later.
2.) Hint will only apply to table. Any index updates that result from
table load will always log. If you want to, you could alter index ...
unusable, then do the load, then alter index ... rebuild nologging;
3.) The problem here is that an INSERT /*+ APPEND */ takes an
*exclusive* lock on the table. This prevents any other DML from running
on the table till that transaction commits. The second process will
wait on the exclusive mode TM enqueue that the first process is holding.
Hope that helps,
-Mark
Mark J. Bobak
Oracle DBA
ProQuest Company
Ann Arbor, MI
"Post Hoc Ergo Propter Hoc"
-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org] On Behalf Of Harvinder Singh
Sent: Friday, June 18, 2004 2:43 PM
To: oracle-l_at_freelists.org
Subject: Question about Append hint in Insert
Hi,
We are testing insert performance in one of out tables and we are
selecting from 1 table 1000 rows at a time and inserting in 2nd table.
So we were getting tps of about 17000 for 1 million records. Then I
added append hint to insert and tps went up to 23000. Now if I a try to
insert from 2 clients to increase scalibility both insert at tps of
11000. so I have 2 questions:
1) What is the disadvantage of adding append hint during insert (we
never delete or update this table in production)
2) Will the hint applicable to all the indexes or only table
3) Why with 2 clients using append result in less tps than normal 2
client inserts?
Thanks
--Harvinder
=3D20
-- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html ----------------------------------------------------------------- -- Binary/unsupported file stripped by Ecartis -- -- Type: application/octet-stream -- File: nologdemo.LST -- Attached file included as plaintext by Ecartis -- -- File: nologdemo.sql set echo on head on message on feedback on trimspool on timi off pause off autotrace off column name format a20 drop table dmk; spool nologdemo clear screen select * from v$version; create table dmk nologging as select * from dba_objects where 1=2 ; truncate table dmk; ttitle before-noindex select s.name, s.value sysstat, m.value mystat from v$sysstat s, v$mystat m where s.name = 'redo size' and s.statistic# = m.statistic# / insert /*+ APPEND NOLOGGING */ into dmk select * from dba_objects where rownum <= 1000; commit / ttitle after-noindex select s.name, s.value sysstat, m.value mystat from v$sysstat s, v$mystat m where s.name = 'redo size' and s.statistic# = m.statistic# / create index dmk on dmk(owner, objecT_name) nologging ; ttitle before+index select s.name, s.value sysstat, m.value mystat from v$sysstat s, v$mystat m where s.name = 'redo size' and s.statistic# = m.statistic# / insert /*+ APPEND NOLOGGING */ into dmk select * from dba_objects where rownum <= 1000; commit / ttitle after+index select s.name, s.value sysstat, m.value mystat from v$sysstat s, v$mystat m where s.name = 'redo size' and s.statistic# = m.statistic# / spool off drop table dmk; ---------------------------------------------------------------- Please see the official ORACLE-L FAQ: http://www.orafaq.com ---------------------------------------------------------------- To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line. -- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html -----------------------------------------------------------------Received on Fri Jun 18 2004 - 17:02:53 CDT
![]() |
![]() |