ACE Director Alum Daniel Morgan, founder of Morgan's Library, is scheduling
complimentary technical Workshops on Database Security for the first 30
Oracle Database customers located anywhere in North America, EMEA, LATAM, or
APAC that send an email to
asra_us@oracle.com. Request a Workshop for
your organization today.
Purpose
Data corruption repair procedures that enable detection and repair of corrupt blocks in tables and indexes. It can be used to address corruptions where possible and continue to use objects while attempting to rebuild or repair them.
dbms_repair.admin_tables(
table_name IN VARCHAR2 DEFAULT 'GENERATE_DEFAULT_TABLE_NAME',
table_type IN BINARY_INTEGER,
action IN BINARY_INTEGER,
tablespace IN VARCHAR2 DEFAULT NULL);
Checks the specified objects and populates the repair table with information about corruptions and repair directives.
Validation consists of block checking all blocks in the object. You may optionally specify a DBA range, partition name, or subpartition name when you want to check a portion of an object.
Before this demo is run the ADMIN_TABLES procedure must be used to create the repair table.
dbms_repair.check_object(
schema_name IN VARCHAR2,
object_name IN VARCHAR2,
partition_name IN VARCHAR2 DEFAULT NULL,
object_type IN BINARY_INTEGER DEFAULT TABLE_OBJECT,
repair_table_name IN VARCHAR2 DEFAULT 'REPAIR_TABLE',
flags IN BINARY_INTEGER DEFAULT NULL,
relative_fno IN BINARY_INTEGER DEFAULT NULL,
block_start IN BINARY_INTEGER DEFAULT NULL,
block_end IN BINARY_INTEGER DEFAULT NULL,
corrupt_count OUT BINARY_INTEGER);
conn uwclass/uwclass@pdbdev
CREATE TABLE badtab AS
SELECT DISTINCT object_name
FROM all_objects;
conn sys@pdbdev as sysdba
set serveroutput on
DECLARE
i BINARY_INTEGER;
BEGIN
dbms_repair.check_object(schema_name=>'UWCLASS', object_name=>'SERVERS', corrupt_count=>i);
dbms_output.put_line(i);
END;
/
This procedure reports on index entries that point to rows in corrupt data blocks. For each such index entry encountered, a row is inserted into the specified orphan table.
If the repair table is specified, then any corrupt blocks associated with the base table are handled in addition to all data blocks that are marked software corrupt. Otherwise, only blocks that are marked corrupt are handled.
This information may be useful for rebuilding lost rows in the table and for diagnostic purposes.
dbms_repair.dump_orphan_keys(
schema_name IN VARCHAR2,
object_name IN VARCHAR2,
partition_name IN VARCHAR2 DEFAULT NULL,
object_type IN BINARY_INTEGER DEFAULT INDEX_OBJECT,
repair_table_name IN VARCHAR2 DEFAULT 'REPAIR_TABLE',
orphan_table_name IN VARCHAR2 DEFAULT 'ORPHAN_KEYS_TABLE',
flags IN BINARY_INTEGER DEFAULT NULL,
key_count OUT BINARY_INTEGER);
set serveroutput on
DECLARE
x BINARY_INTEGER;
BEGIN
dbms_repair.dump_orphan_keys('UWCLASS', 'SERVERS_PK', NULL, 2, 'REPAIR_TABLE', 'ORPHAN_KEYS_TABLE', 1, x);
dbms_output.put_line(x);
END;
/
This procedure fixes the corrupt blocks in specified objects based on information in the repair table that was previously generated by the check_object procedure.
Prior to effecting any change to a block, the block is checked to ensure the block is still corrupt. Corrupt blocks are repaired by marking the block software corrupt. When a repair is effected, the associated row in the repair table is updated with a fix timestamp.
dbms_repair.fix_corrupt_blocks(
schema_name IN VARCHAR2,
object_name IN VARCHAR2,
partition_name IN VARCHAR2 DEFAULT NULL,
object_type IN BINARY_INTEGER DEFAULT TABLE_OBJECT,
repair_table_name IN VARCHAR2 DEFAULT 'REPAIR_TABLE',
flags IN BINARY_INTEGER DEFAULT NULL,
fix_count OUT BINARY_INTEGER);
set serveroutput on
DECLARE
x BINARY_INTEGER;
BEGIN
dbms_repair.fix_corrupt_blocks('UWCLASS', 'SERVERS', NULL, 1, 'REPAIR_TABLE', 1, x);
dbms_output.put_line(x);
END;
/
Rebuilds freelists for the specified object. All free blocks are placed on the master freelist. All other freelists are zeroed.
If the object has multiple freelist groups, then the free blocks are distributed among all freelists, allocating to the different groups in round-robin fashion.
This is discussed in Jonathan Lewis' Cost-Based Oracle Fundamentals
ISBN: 1-59059-636-6, pg 101
dbms_repair.rebuild_freelists(
schema_name IN VARCHAR2,
object_name IN VARCHAR2,
partition_name IN VARCHAR2 DEFAULT NULL,
object_type IN BINARY_INTEGER DEFAULT TABLE_OBJECT);
-- tables in ASSM tablespaces do not have freelists
*
ERROR at line 1:
ORA-10614: Operation not allowed on this segment
ORA-06512: at "SYS.DBMS_REPAIR", line 401
ORA-06512: at line 1
With this procedure you can fix the corrupted state of a bitmap entry.
The procedure either recalculates the state based on the current contents of the corresponding block or sets the state to a specific value.
For segments with automatic ASSM, Oracle ignores attempts to change the PCTUSED setting.
If you alter the PCTFREE setting, then you must subsequently run the DBMS_REPAIR.SEGMENT_FIX_STATUS procedure to implement the new setting on blocks already allocated to the segment.
dbms_repair.segment_fix_status(
segment_owner IN VARCHAR2,
segment_name IN VARCHAR2,
segment_type IN BINARY_INTEGER DEFAULT TABLE_OBJECT,
file_number IN BINARY_INTEGER DEFAULT NULL,
block_number IN BINARY_INTEGER DEFAULT NULL,
status_value IN BINARY_INTEGER DEFAULT NULL,
partition_name IN VARCHAR2 DEFAULT NULL);
Enables or disables skipping corrupt blocks during index and table scans of the specified object. When the object is a table, skip applies to the table and its indexes.
When the object is a cluster, it applies to all of the tables and indexes in the cluster.
dbms_repair.skip_corrupt_blocks(
schema_name IN VARCHAR2,
object_name IN VARCHAR2,
object_type IN BINARY_INTEGER DEFAULT TABLE_OBJECT,
flags IN BINARY_INTEGER DEFAULT SKIP_FLAG);