Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: insert /*+APPEND*/ Unexpected result (more redo log)
it looks as though when using an /*+APPEND*/ hint, that Oracle still does
QMI (array inserts) but each array only contains one or two rows...
Run a report of the actual space used in the table, compared to the amount specified by PCTFREE and you'll see that the actual used space is very low. Check the number of extents on the two tables as well. Also with QMI, Oracle writes additional information to the redo log about the block, and any rowids contained within it. So you are writing out many more redo log blocks than necessary when doing an APPEND.
I'm guessing that with your configuration, that about 12-14 rows of ALL_OBJECTS will fit in a single DB_BLOCK...
-----Original Message-----
Sent: Tuesday, May 06, 2003 9:52 AM
To: Multiple recipients of list ORACLE-L
try
alter table redolog_test nologging;
before the insert append
-----Original Message-----
Sent: Tuesday, May 06, 2003 9:52 AM
To: Multiple recipients of list ORACLE-L
Hi All,
I'm getting UNEXPECTED result in both 8i and 9iR2.
Could someone please tell me why insert /*+APPEND*/ generates more redo log.
I'm pretty sure that there is NO index involved in my test
table(redolog_test).
Also the user is not a SYS and SYSTEM.
The DB is running in ARCHIVE LOG mode.
SQL> show user
USER is "MUT"
SQL> drop table redolog_test;
Table dropped.
SQL> create table redolog_test pctfree 99 pctused 1 as select * from
all_objects
where 1=2;
Table created.
SQL> insert into redolog_test select * from all_objects; 19412 rows created.
Statistics
2003 recursive calls 89992 db block gets 161720 consistent gets 0 physical reads 10661144 redo size <======== 438 bytes sent via SQL*Net to client 433 bytes received via SQL*Net from client 4 SQL*Net roundtrips to/from client 2 sorts (memory) 0 sorts (disk) 19412 rows processed
SQL> truncate table redolog_test;
Table truncated.
SQL> insert /*+APPEND*/ into redolog_test select * from all_objects; 19412 rows created.
Statistics
2012 recursive calls 365 db block gets 142229 consistent gets 0 physical reads 159534376 redo size <=======(15 Times higher) 430 bytes sent via SQL*Net to client 445 bytes received via SQL*Net from client 4 SQL*Net roundtrips to/from client 2 sorts (memory) 0 sorts (disk) 19412 rows processed
--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Nick Wagner
INET: Nick.Wagner_at_quest.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 May 06 2003 - 12:32:02 CDT