RE: ORA-1578...block corrupted...error is normal...a block...had a NOLOGGING...operation performed against

  • From: "Allen, Brandon" <Brandon.Allen@xxxxxxxxxxx>
  • To: "Jared Still" <jkstill@xxxxxxxxx>
  • Date: Tue, 23 Aug 2005 17:11:10 -0700

Here is another test indicating that a direct-path insert to a nologging index 
is actually logged (like Jared has also shown), which is contrary to the 
documentation.  

Notice that both the table and the index are created as NOLOGGING, but the 
tablespace containing the index (TOOLS) only gets marked as unrecoverable at 
the time of the index creation (16:42) and the unrecoverable time is not 
updated after the direct-path insert, whereas the tablespace containing the 
table (SYSTEM) *does* have its unrecoverable time updated at the time of the 
direct-path insert (16:48).  So, it appears the table changes are not logged, 
and therefore are unrecoverable as would be expected, but the index changes 
*are* still logged and therefore the index is recoverable, contrary to the 
documentation:

SQL>create table t_nolog tablespace system nologging as select * from 
all_objects;

Table created.

SQL>create index t_nolog_idx on t_nolog (object_type, object_name) tablespace 
tools nologging;

Index created.

SQL>select tablespace_name, logging from user_tables where table_name = 
'T_NOLOG';

TABLESPACE_NAME                LOG
------------------------------ ---
SYSTEM                         NO

SQL>select tablespace_name, logging from user_indexes where index_name = 
'T_NOLOG_IDX';

TABLESPACE_NAME                LOG
------------------------------ ---
TOOLS                          NO

SQL>insert /*+ APPEND */ into t_nolog select * from all_objects;

3005 rows created.

SQL>commit;

Commit complete.

SQL>select name, unrecoverable_time from v$datafile;

NAME                                               UNRECOVERABLE_TIME
-------------------------------------------------- ------------------
/u07/oradat/vrtxtst/system01.dbf                   23-AUG-05 16:48:13
/u07/oradat/vrtxtst/undotbs01.dbf
/u07/oradat/vrtxtst/tools01.dbf                    23-AUG-05 16:41:17
/u07/oradat/vrtxtst/vertex01.dbf

SQL>insert /*+ APPEND */ into t_nolog select * from all_objects;

3005 rows created.

SQL>commit;

Commit complete.

SQL>select name, unrecoverable_time from v$datafile;

NAME                                               UNRECOVERABLE_TIME
-------------------------------------------------- ------------------
/u07/oradat/vrtxtst/system01.dbf                   23-AUG-05 17:01:35
/u07/oradat/vrtxtst/undotbs01.dbf
/u07/oradat/vrtxtst/tools01.dbf                    23-AUG-05 16:41:17
/u07/oradat/vrtxtst/vertex01.dbf



-----Original Message-----
From: Jared Still [mailto:jkstill@xxxxxxxxx]
Sent: Tuesday, August 23, 2005 3:25 PM
To: Allen, Brandon
Cc: oracle-l@xxxxxxxxxxxxx
Subject: Re: ORA-1578...block corrupted...error is normal...a block...had a 
NOLOGGING...operation performed against


I don't see any corruption.  
Notice the index full scan below.
Also see the 10046 trace data following the test output.

15:21:49 SQL>
15:21:49 SQL>alter table nolog_test modify(owner not null, object_name not 
null, object_type not null);

Table altered.

15:21:49 SQL>
15:21:49 SQL>exec 
dbms_stats.gather_table_stats(user,tabname=>'NOLOG_TEST',cascade=>true,estimate_percent=>100)

PL/SQL procedure successfully completed.

15:21:52 SQL>
15:21:52 SQL>analyze index nolog_test_idx validate structure;

Index analyzed.

15:21:52 SQL>
15:21:52 SQL>select * from index_stats;

    HEIGHT      BLOCKS NAME                           PARTITION_NAME            
        LF_ROWS
---------- ----------- ------------------------------ 
------------------------------ ----------
   LF_BLKS LF_ROWS_LEN LF_BLK_LEN    BR_ROWS    BR_BLKS BR_ROWS_LEN BR_BLK_LEN 
DEL_LF_ROWS
---------- ----------- ---------- ---------- ---------- ----------- ---------- 
-----------
                                                                        PCT
DEL_LF_ROWS_LEN DISTINCT_KEYS MOST_REPEATED_KEY BTREE_SPACE USED_SPACE USED 
ROWS_PER_KEY
--------------- ------------- ----------------- ----------- ---------- ---- 
------------
BLKS_GETS_PER_ACCESS   PRE_ROWS PRE_ROWS_LEN OPT_CMPR_COUNT OPT_CMPR_PCTSAVE
-------------------- ---------- ------------ -------------- ----------------
         3         512 NOLOG_TEST_IDX                                           
          64988
       481     3144140       7996        480          4       14505       8028  
         0
              0         32355                32     3878188    3158645   82   
2.00859218
          4.50429609          0            0              3               32


1 row selected.

15:21:52 SQL>
15:21:52 SQL>select index_name, num_rows from user_indexes where index_name = 
'NOLOG_TEST_IDX';

INDEX NAME                       NUM_ROWS
------------------------------ ----------
NOLOG_TEST_IDX                      64988

1 row selected.

15:21:52 SQL>
15:21:52 SQL>select table_name, blocks, num_rows from user_tables where 
table_name = 'NOLOG_TEST';

TABLE NAME                          BLOCKS   NUM_ROWS
------------------------------ ----------- ----------
NOLOG_TEST                             960      64988

1 row selected.

15:21:52 SQL>
15:21:52 SQL>select count(*) from nolog_test;

  COUNT(*)
----------
     64988

1 row selected.

15:21:52 SQL>
15:21:52 SQL>set autotrace on
15:21:52 SQL>
15:21:52 SQL>select count(*)
15:21:52   2  from (
15:21:52   3  select owner,object_type,object_name
15:21:52   4  from nolog_test
15:21:52   5  )
15:21:52   6  /

  COUNT(*)
----------
     64988

1 row selected.


Execution Plan
----------------------------------------------------------
          0
SELECT STATEMENT Optimizer=CHOOSE (Cost=574 Card=1)


          1                  0
  SORT (AGGREGATE)


          2                  1
    INDEX (FULL SCAN) OF 'NOLOG_TEST_IDX' (NON-UNIQUE) (Cost=574 Card=64988)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        483  consistent gets
          0  physical reads
          0  redo size
        381  bytes sent via SQL*Net to client
        383  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

15:21:52 SQL>
15:21:52 SQL>set autotrace off
15:21:52 SQL>
15:21:52 SQL>spool off

************** 10046 trace

PARSING IN CURSOR #3 len=77 dep=0 uid=101 oct=3 lid=101 tim=1098472512646433 
hv=1860683524 ad='5757265c'
select count(*)
from (
select owner,object_type,object_name
from nolog_test
)
END OF STMT
PARSE #3:c=0,e=957,p=0,cr=0,cu=0,mis=1,r=0,dep=0,og=4,tim=1098472512646418
BINDS #3:
EXEC #3:c=0,e=97,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=4,tim=1098472512646783
WAIT #3: nam='SQL*Net message to client' ela= 3 p1=1413697536 p2=1 p3=0
FETCH 
#3:c=20000,e=24456,p=0,cr=483,cu=0,mis=0,r=1,dep=0,og=4,tim=1098472512671338
WAIT #3: nam='SQL*Net message from client' ela= 390 p1=1413697536 p2=1 p3=0
FETCH #3:c=0,e=3,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=0,tim=1098472512672047
WAIT #3: nam='SQL*Net message to client' ela= 2 p1=1413697536 p2=1 p3=0
WAIT #3: nam='SQL*Net message from client' ela= 547 p1=1413697536 p2=1 p3=0
*** SESSION ID:(9.13) 2005-08-23 15:24:13.041
STAT #3 id=1 cnt=1 pid=0 pos=1 obj=0 op='SORT AGGREGATE '
STAT #3 id=2 cnt=64988 pid=1 pos=1 obj=48350 op='INDEX FULL SCAN NOLOG_TEST_IDX 
'




On 8/23/05, Allen, Brandon <Brandon.Allen@xxxxxxxxxxx> wrote:
Thanks Jared, I'll do some more tests to see if I can figure out exactly what's 
going on.  I suspect that the direct-insert is minimally logged as it says in 
the documentation, but perhaps there is still a signifcant amount from 
dictionary updates due to block splits and other recursive activity, and when 
you recover, the direct-inserted blocks are corrupt, but the select statement 
you ran for the regular (non-direct, logged) insert did not need to touch those 
corrupt blocks so it completed just fine - but if you forced a full index scan, 
you would see the corruption.

-----Original Message-----
From: Jared Still [mailto:jkstill@xxxxxxxxx]

Sent: Tuesday, August 23, 2005 2:47 PM
To: Allen, Brandon
Cc: oracle-l@xxxxxxxxxxxxx
Subject: Re: ORA-1578...block corrupted...error is normal...a block...had a 
NOLOGGING...operation performed against


v$datafile
FILE_NAME
----------------------------------------------------------------------------------------------------
STATUS  UNRECOVERABLE_TIME  UNRECOVERABLE_CHANGE#
------- ------------------- ---------------------
/u01/oradata/dv03/test01.dbf
ONLINE  08/23/2005 12:33:51            1039632753

---------------------------------------------------------------

14:44:28 SQL>l
  1* select * from v$backup_corruption
14:44:29 SQL>/
 
no rows selected
 
--------------------------------------------------------------

DBV: I have not included any dbv output.
dbv reports every file I test as corrupt ( including SYSTEM)
This is with the database shutdown.
Don't know what the problem there is, but I'm not going to 
pursue it right now.

Jared




On 8/23/05, Allen, Brandon <Brandon.Allen@xxxxxxxxxxx > wrote: 
Thanks for the great test case Jared - just a few questions:

Can you check the following to see if there is any indication of corruption due 
to the recovery through the nologging operation:

 - v$datafile: unrecoverable_time & unrecoverable_change# columns
 - v$backup_corruption
 - run dbverify on the datafile

Have you submitted your case to Oracle support to see if it is a bug, or if 
we're all missing something?

Thanks again,
Brandon

-----Original Message-----
From: Jared Still [mailto: jkstill@xxxxxxxxx]
Sent: Tuesday, August 23, 2005 12:46 PM
To: Hemant K Chitale
Cc: Allen, Brandon; cmarquez@xxxxxxxxxxxxxxxx; oracle-l@xxxxxxxxxxxxx
Subject: Re: ORA-1578...block corrupted...error is normal...a block...had a 
NOLOGGING...operation performed against




On 8/23/05, Hemant K Chitale <hkchital@xxxxxxxxxxxxxx> wrote: 

Jared,

You ARE right.  You really don't need to retest it.  

Maybe not, but I want to.


Privileged/Confidential Information may be contained in this message or 
attachments hereto. Please advise immediately if you or your employer do not 
consent to Internet email for messages of this kind. Opinions, conclusions and 
other information in this message that do not relate to the official business 
of this company shall be understood as neither given nor endorsed by it.



-- 
Jared Still
Certifiable Oracle DBA and Part Time Perl Evangelist


Privileged/Confidential Information may be contained in this message or 
attachments hereto. Please advise immediately if you or your employer do not 
consent to Internet email for messages of this kind. Opinions, conclusions and 
other information in this message that do not relate to the official business 
of this company shall be understood as neither given nor endorsed by it.



-- 
Jared Still
Certifiable Oracle DBA and Part Time Perl Evangelist
--
//www.freelists.org/webpage/oracle-l

Other related posts: