Disclaimer

These scripts come without warranty of any kind. Use them at your own risk. I assume no liability for the accuracy, correctness, completeness, or usefulness of any information provided by this site nor for any sort of damages using these scripts may cause.

Tuesday, August 2, 2011

Salvage Data from corrupted Oracle Table

Recently, when i query a table with full table scan it gives error and i failing.
It given error ORA-8103 object no longer exists
Then i tried to do analyze the table using validate structure option, that also given same error.
SO it look like there is some kond of corruption. I restored some old backup and checked the table again, that also reported the same error.
Now i will not be able to restore the table from the backup as error persist for long time.
I have two indexs attached to this table, so I tried analyzing the Indexes and that also reported same error.
Then i tried to repair the table using DBMS_REPAIR package and it crashed with ORA-600 error.
Now i have only one option left, somehow extract the data that can be retrived from the table.
Oracle is providing a method to retrive recoverable rows by getting rowid of the row using index. Recovered rows will be insert into new table.

table data can be saved by skipping the blocks that are causing the ORA-8103 error:
Following are the step i performed to recover data.
Disclaimer: This is just for information and accademic purpose only.

Pre-requisite: Table must have an indexed column.
Step 1: Create a new table structure similar to original table
Create table <new table name> as select * from <original table name>
where 1<>1
Step 2: Create a table to store bad row's rowid and error numnber.
create table bad_rows (row_id rowid
                      ,oracle_error_code number);
Step 3: Recover Data by executing below pl/sql block (Replace the table names, columns as per your need)
set serveroutput on
DECLARE
  TYPE RowIDTab IS TABLE OF ROWID INDEX BY BINARY_INTEGER;
  CURSOR c1 IS select /*+ index(tab1) */ rowid
  from <original table name> tab1
  where <indexed column> is NOT NULL;
  r RowIDTab;
  rows NATURAL := 20000;
  bad_rows number := 0 ;
  errors number;
  error_code number;
  myrowid rowid;
BEGIN
  OPEN c1;
  LOOP
   FETCH c1 BULK COLLECT INTO r LIMIT rows;
   EXIT WHEN r.count=0;
   BEGIN
    FORALL i IN r.FIRST..r.LAST SAVE EXCEPTIONS
     insert into <new table name>
     select /*+ ROWID(A) */ <list of columns from table (ie col1, col2,..)>
     from <original table name> A where rowid = r(i);
   EXCEPTION
   when OTHERS then
    BEGIN
     errors := SQL%BULK_EXCEPTIONS.COUNT;
     FOR err1 IN 1..errors LOOP
      error_code := SQL%BULK_EXCEPTIONS(err1).ERROR_CODE;
      if error_code in (1410, 8103) then
       myrowid := r(SQL%BULK_EXCEPTIONS(err1).ERROR_INDEX);
       bad_rows := bad_rows + 1;
       insert into bad_rows values(myrowid, error_code);
      else
       raise;
      end if;
     END LOOP;
    END;
   END;
   commit;
  END LOOP;
  commit;
  CLOSE c1;
  dbms_output.put_line('Total Bad Rows: '||bad_rows);
END;
/

Step 4: Note down the indexes on original table for creating on new table
Step 5: Rename the Original Table
Step 6: Drop the indexes
Step 7: Rename the new table to original table name
Step 8: Recreate the indexes
Step 9: Recreate the synoyms & grants
Step 10: Compile invalid objects any depends on this table.
========================

No comments: