Skip Headers
Oracle® Database PL/SQL Packages and Types Reference
10g Release 2 (10.2)

Part Number B14258-01
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page
Previous
Go to next page
Next
View PDF

99 DBMS_SPACE_ADMIN

The DBMS_SPACE_ADMIN package provides functionality for locally managed tablespaces.


See Also:

Oracle Database Administrator's Guide for an example and description of using DBMS_SPACE_ADMIN.

This chapter contains the following topics:


Using DBMS_SPACE_ADMIN

This section contains topics which relate to using the DBMS_SPACE_ADMIN package.


Security Model

This package runs with SYS privileges; therefore, any user who has privilege to execute the package can manipulate the bitmaps.


Constants

Table 99-1 DBMS_SPACE_ADMIN Constants

Constant Type Value Description
SEGMENT_VERIFY_EXTENTS POSITIVE 1 Verifies that the space owned by segment is appropriately reflected in the bitmap as used
SEGMENT_VERIFY_EXTENTS_GLOBAL POSITIVE 2 Verifies that the space owned by segment is appropriately reflected in the bitmap as used and that no other segment claims any of this space to be used by it
SEGMENT_MARK_CORRUPT POSITIVE 3 Marks a temporary segment as corrupt whereby facilitating its elimination from the dictionary (without space reclamation).
SEGMENT_MARK_VALID POSITIVE 4 Marks a corrupt temporary segment as valid. It is useful when the corruption in the segment extent map or elsewhere has been resolved and the segment can be dropped normally.
SEGMENT_DUMP_EXTENT_MAP POSITIVE 5 Dumps the extent map for a given segment
TABLESPACE_VERIFY_BITMAP POSITIVE 6 Verifies the bitmap of the tablespace with extent maps of the segments in that tablespace to make sure everything is consistent
TABLESPACE_EXTENT_MAKE_FREE POSITIVE 7 Marks the DBA range (extent) as free in the bitmaps
TABLESPACE_EXTENT_MAKE_USED POSITIVE 8 Marks the DBA range (extent) as used in the bitmaps
SEGMENT_VERIFY_BASIC POSITIVE 9 Performs the basic metadata checks
SEGMENT_VERIFY_DEEP POSITIVE 10 Performs deep verification
SEGMENT_VERIFY_SPECIFIC POSITIVE 11 Performs a specific check for the segment
HWM_CHECK POSITIVE 12 Checks HWM
BMB_CHECK POSITIVE 13 Checks integrity among L1, L2 and L3 BMBs
SEG_DICT_CHECK POSITIVE 14 Checks consistency of segment header with corresponding SEG entry
EXTENT_TS_BITMAP_CHECK POSITIVE 15 Checks whether the tablespace bitmaps corresponding to the extent map are marked used
DB_BACKPOINTER_CHECK POSITIVE 16 Checks whether the L1 BMBs, L2 BMBs, L3 BMBs and data blocks point to the same parent segment
EXTENT_SEGMENT_BITMAP_CHECK POSITIVE 17 Checks whether the bitmap blocks are consistent with the extent map
BITMAPS_CHECK POSITIVE 18 Checks from the datablocks that the bitmap states representing the blocks are consistent
TS_VERIFY_BITMAPS POSITIVE 19 Checks whether the tablespace bitmaps are consistent with the extents belonging to that tablespace
TS_VERIFY_DEEP POSITIVE 20 Performs TS_VERIFY_BITMAPS and TS_VERIFY_SEGMENTS with DEEP option
TS_VERIFY_SEGMENTS POSITIVE 21 Performs ASSM_SEGMENT_VERIFY on all segments in the tablespace. will take either the basic or the deep option
SEGMENTS_DUMP_BITMAP_SUMMARY POSITIVE 27 Dumps only bitmap block summaries


Operational Notes

Before migrating the SYSTEM tablespace, the following conditions must be met. These conditions are enforced by the TABLESPACE_MIGRATE_TO_LOCAL procedure, except for the cold backup.


Summary of DBMS_SPACE_ADMIN Subprograms

Table 99-2 DBMS_SPACE_ADMIN Package Subprograms

Subprogram Description
ASSM_SEGMENT_VERIFY Procedure
Verifies segments created in ASSM tablespaces
ASSM_TABLESPACE_VERIFY Procedure
Verifies ASSM tablespaces
SEGMENT_CORRUPT Procedure
Marks the segment corrupt or valid so that appropriate error recovery can be done
SEGMENT_DROP_CORRUPT Procedure
Drops a segment currently marked corrupt (without reclaiming space)
SEGMENT_DUMP Procedure
Dumps the segment header and extent maps of a given segment
SEGMENT_VERIFY Procedure
Verifies the consistency of the extent map of the segment
TABLESPACE_FIX_BITMAPS Procedure
Marks the appropriate DBA range (extent) as free or used in bitmap
TABLESPACE_FIX_SEGMENT_STATES Procedure Fixes the state of the segments in a tablespace in which migration was aborted
TABLESPACE_MIGRATE_FROM_LOCAL Procedure
Migrates a locally-managed tablespace to dictionary-managed tablespace
TABLESPACE_MIGRATE_TO_LOCAL Procedure
Migrates a tablespace from dictionary managed format to locally managed format
TABLESPACE_REBUILD_BITMAPS Procedure
Rebuilds the appropriate bitmaps
TABLESPACE_REBUILD_QUOTAS Procedure
Rebuilds quotas for given tablespace
TABLESPACE_RELOCATE_BITMAPS Procedure
Relocates the bitmaps to the destination specified
TABLESPACE_VERIFY Procedure
Verifies that the bitmaps and extent maps for the segments in the tablespace are in sync


ASSM_SEGMENT_VERIFY Procedure

Given a segment definition, the procedure verifies the basic consistency of the space metadata blocks as well as consistency between space metadata and segment data blocks. This procedure verifies segments created in ASSM (Automatic Segment Space Management) tablespaces.

There is however a difference between basic verification and deep verification:

Syntax

DBMS_SPACE_ADMIN.ASSM_SEGMENT_VERIFY (
   segment_owner   IN VARCHAR2,
   segment_name    IN VARCHAR2,
   segment_type    IN VARCHAR2,
   partition_name  IN VARCHAR2,
   verify_option   IN POSITIVE  DEFAULT SEGMENT_VERIFY_BASIC,
   attrib          IN POSITIVE  DEFAULT NULL);

Parameters

Table 99-3 ASSM_SEGMENT_VERIFY Procedure Parameters

Parameter Description
segment_owner The schema that owns the segment
segment_name The name of the segment to be verified
segment_type The segment namespace is one of TABLE, TABLE PARTITION, TABLE SUBPARTITION, INDEX, INDEX PARTITION, INDEX SUBPARTITION, LOB, LOB PARTITION, LOB SUBPARTITION, CLUSTER
partition_name Name of the partition or subpartition
verify_option
  • SEGMENT_VERIFY_DEEP: Perform deep verification
  • SEGMENT_VERIFY_BASIC: Perform the basic metadata checks (Default)

attrib Used when option SEGMENT_VERIFY_SPECIFIC

Usage Notes


ASSM_TABLESPACE_VERIFY Procedure

This procedures verifies all the segments created in an ASSM tablespace. The verification per segment is either basic consistency checks of the space metadata blocks as well as consistency checks between space metadata and segment data blocks.

Syntax

DBMS_SPACE_ADMIN.ASSM_TABLESPACE_VERIFY (
   tablespace_name   IN VARCHAR2,
   ts_option         IN POSITIVE,
   segment_option    IN POSITIVE DEFAULT NULL);

Parameters

Table 99-4 ASSM_TABLESPACE_VERIFY Procedure Parameters

Parameter Description
tablespace_name Name of the tablespace to verify, tablespace should be ASSM
ts_option
  • TABLESPACE_VERIFY_BITMAPS: The bitmaps are verified against the extents. This will detect bits that are marked used or free wrongly and will also detect multiple allocation of extents. The file metadata will be validated against file$ and control file. This is the default option (1).
  • TABLESPACE_VERIFY_DEEP: This option is used to verify the file bitmaps as well perform checks on all the segments (2).

  • TABLESPACE_VERIFY_SEGMENTS: This option is used to invoke SEGMENT_VERIFY on all the segments in the tablespace. Optionally the user can write a script that queries all the segments in the tablespace and invoke SEGMENT_VERIFY (3).

segment_option This is same as OPTION specified for SEGMENT_VERIFY procedure. When the TABLESPACE_VERIFY_SEGMENTS or TABLESPACE_VERIFY_DEEP is chosen, the SEGMENT_OPTION can be specified optionally. The only valid segment options applicable are SEGMENT_VERIFY_DEEP and SEGMENT_VERIFY_BASIC.

Usage Notes

Using this procedure requires SYSDBA privileges to execute.

This procedure outputs a dump file named sid_ora_process_ID.trc to the location specified in the USER_DUMP_DEST initialization parameter.


SEGMENT_CORRUPT Procedure

This procedure marks the segment corrupt or valid so that appropriate error recovery can be done. It cannot be used on the SYSTEM tablespace.

Syntax

DBMS_SPACE_ADMIN.SEGMENT_CORRUPT (
   tablespace_name         IN    VARCHAR2,
   header_relative_file    IN    POSITIVE,
   header_block            IN    POSITIVE,
   corrupt_option          IN    POSITIVE  DEFAULT SEGMENT_MARK_CORRUPT);

Parameters

Table 99-5 SEGMENT_CORRUPT Procedure Parameters

Parameter Description
tablespace_name Name of tablespace in which segment resides.
header_relative_file Relative file number of segment header.
header_block Block number of segment header.
corrupt_option SEGMENT_MARK_CORRUPT (default) or SEGMENT_MARK_VALID.

Examples

The following example marks the segment as corrupt:

EXECUTE DBMS_SPACE_ADMIN.SEGMENT_CORRUPT('USERS', 4, 33, 3); 

Alternately, the next example marks a corrupt segment valid:

EXECUTE DBMS_SPACE_ADMIN.SEGMENT_CORRUPT('USERS', 4, 33, 4); 

SEGMENT_DROP_CORRUPT Procedure

This procedure drops a segment currently marked corrupt (without reclaiming space). For this to work, the segment should have been marked temporary. To mark a corrupt segment as temporary, issue a DROP command on the segment.

Syntax

DBMS_SPACE_ADMIN.SEGMENT_DROP_CORRUPT (
   tablespace_name         IN    VARCHAR2,
   header_relative_file    IN    POSITIVE,
   header_block            IN    POSITIVE);

Parameters

Table 99-6 SEGMENT_DROP_CORRUPT Procedure Parameters

Parameter Description
tablespace_name Name of tablespace in which segment resides.
header_relative_file Relative file number of segment header.
header_block Block number of segment header.

Usage Notes

The procedure cannot be used on the SYSTEM tablespace.

The space for the segment is not released, and it must be fixed by using the TABLESPACE_FIX_BITMAPS Procedure or the TABLESPACE_REBUILD_BITMAPS Procedure.

Examples

EXECUTE DBMS_SPACE_ADMIN.SEGMENT_DROP_CORRUPT('USERS', 4, 33); 

SEGMENT_DUMP Procedure

This procedure dumps the segment header and bitmap blocks of a specific segment to the location specified in the USER_DUMP_DEST initialization parameter.

Syntax

DBMS_SPACE_ADMIN.SEGMENT_DUMP (
   tablespace_name         IN    VARCHAR2,
   header_relative_file    IN    POSITIVE,
   header_block            IN    POSITIVE,
   dump_option             IN    POSITIVE  DEFAULT SEGMENT_DUMP_EXTENT_MAP);

Parameters

Table 99-7 SEGMENT_DUMP Procedure Parameters

Parameter Description
tablespace_name Name of tablespace in which segment resides.
header_relative_file Relative file number of segment header.
header_block Block number of segment header.
dump_option SEGMENT_DUMP_EXTENT_MAP.

SEGMENT_DUMP_BITMAP_SUMMARY.


Usage Notes

Examples

EXECUTE DBMS_SPACE_ADMIN.SEGMENT_DUMP('USERS', 4, 33); 

SEGMENT_VERIFY Procedure

This procedure checks the consistency of the segment extent map with the tablespace file bitmaps.

Syntax

DBMS_SPACE_ADMIN.SEGMENT_VERIFY (
   tablespace_name         IN    VARCHAR2,
   header_relative_file    IN    POSITIVE,
   header_block            IN    POSITIVE,
   verify_option           IN    POSITIVE  DEFAULT SEGMENT_VERIFY_EXTENTS);

Parameters

Table 99-8 SEGMENT_VERIFY Procedure Parameters

Parameters Description
tablespace_name Name of tablespace in which segment resides.
header_relative_file Relative file number of segment header.
header_block Block number of segment header.
verify_option What kind of check to do: SEGMENT_VERIFY_EXTENTS or SEGMENT_VERIFY_EXTENTS_GLOBAL.

Usage Notes

Anomalies are output as dba-range, bitmap-block, bitmap-block-range, anomaly-information, in the trace file for all dba-ranges found to have incorrect space representation. The kinds of problems which would be reported are free space not considered free, used space considered free, and the same space considered used by multiple segments.

Examples

The following example verifies that the segment with segment header at relative file number 4, block number 33, has its extent maps and bitmaps in sync.

EXECUTE DBMS_SPACE_ADMIN.SEGMENT_VERIFY('USERS', 4, 33, 1); 


Note:

All DBMS_SPACE_ADMIN package examples use the tablespace USERS which contains SCOTT.EMP.


TABLESPACE_FIX_BITMAPS Procedure

This procedure marks the appropriate DBA range (extent) as free or used in bitmap. It cannot be used on the SYSTEM tablespace.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_FIX_BITMAPS (
   tablespace_name         IN    VARCHAR2,
   dbarange_relative_file  IN    POSITIVE,
   dbarange_begin_block    IN    POSITIVE,
   dbarange_end_block      IN    POSITIVE,
   fix_option              IN    POSITIVE);

Parameters

Table 99-9 TABLESPACE_FIX_BITMAPS Procedure Parameters

Parameter Description
tablespace_name Name of tablespace.
dbarange_relative_file Relative file number of DBA range (extent).
dbarange_begin_block Block number of beginning of extent.
dbarange_end_block Block number (inclusive) of end of extent.
fix_option TABLESPACE_EXTENT_MAKE_FREE or TABLESPACE_EXTENT_MAKE_USED.

Examples

The following example marks bits for 51 blocks for relative file number 4, beginning at block number 33 and ending at 83, as USED in bitmaps.

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_FIX_BITMAPS('USERS', 4, 33, 83, 7); 

Alternately, specifying an option of 8 marks the bits FREE in bitmaps. The BEGIN and END blocks should be in extent boundary and should be extent multiple. Otherwise, an error is raised.


TABLESPACE_FIX_SEGMENT_STATES Procedure

Use this procedure to fix the state of the segments in a tablespace in which migration was aborted. During tablespace migration to or from local, the segments are put in a transient state. If migration is aborted, the segment states are corrected by SMON when event 10906 is set. Database with segments in such a transient state cannot be downgraded. The procedure can be used to fix the state of such segments.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_FIX_SEGMENT_STATES (
   tablespace_name     IN    VARCHAR);

Parameters

Table 99-10 TABLESPACE_FIX_SEGMENT_STATES Procedure Parameters

Parameter Name Purpose
tablespace_name Name of the tablespace whose segments need to be fixed.

Usage Notes

The tablespace must be kept online and read/write when this procedure is called.

Examples

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_FIX_SEGMENT_STATES('TS1') 

TABLESPACE_MIGRATE_FROM_LOCAL Procedure

This procedure migrates a locally-managed tablespace to a dictionary-managed tablespace. You cannot use this procedure for SYSTEM tablespace.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_MIGRATE_FROM_LOCAL (
   tablespace_name         IN    VARCHAR2);

Parameter

Table 99-11 TABLESPACE_MIGRATE_FROM_LOCAL Procedure Parameter

Parameter Description
tablespace_name Name of tablespace.

Usage Notes

The tablespace must be kept online and read/write during migration. Migration of temporary tablespaces and migration of SYSTEM tablespaces are not supported.

Examples

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_MIGRATE_FROM_LOCAL('USERS'); 

TABLESPACE_MIGRATE_TO_LOCAL Procedure

Use this procedure to migrate the tablespace from a dictionary-managed format to a locally managed format. Tablespaces migrated to locally managed format are user managed.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_MIGRATE_TO_LOCAL (
   tablespace_name     IN     VARCHAR,
   unit_size           IN     POSITIVE DEFAULT NULL,
   rfno                IN     INTGER DEFAULT NULL);

Parameters

Table 99-12 TABLESPACE_MIGRATE_TO_LOCAL Procedure Parameters

Parameter Name Purpose
tablespace_name Name of the tablespace to be migrated.
unit_size Unit size (which is the size of the smallest possible chunk of space that can be allocated) in the tablespace.
rfno Relative File Number of the file where the bitmap blocks should be placed (optional).

Usage Notes

Before you migrate the SYSTEM tablespace, you should migrate any dictionary-managed tablespaces that you may want to use in read/write mode to locally managed. After the SYSTEM tablespace is migrated, you cannot change dictionary-managed tablespaces to read/write.

The tablespace must be kept online and read/write during migration. Note that temporary tablespaces cannot be migrated.

Allocation Unit may be specified optionally. The default is calculated by the system based on the highest common divisor of all extents (used or free) for the tablespace. This number is further trimmed based on the MINIMUM EXTENT for the tablespace (5 if MINIMUM EXTENTT is not specified). Thus, the calculated value will not be larger than the MINIMUM EXTENT for the tablespace. The last free extent in every file will be ignored for GCD calculation. If you specify the unit size, it has to be a factor of the UNIT size calculated by the system, otherwise an error message is returned.

The Relative File Number parameter is used to place the bitmaps in a desired file. If space is not found in the file, an error is issued. The data file specified should be part of the tablespace being migrated. If the dataflow is not specified then the system will choose a dataflow in which to place the initial bitmap blocks. If space is not found for the initial bitmaps, an error will be raised.

Examples

To migrate a tablespace 'TS1' with minimum extent size 1m, use

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_MIGRATE_TO_LOCAL('TS1', 512, 2);

The bitmaps will be placed in file with relative file number 2.


TABLESPACE_REBUILD_BITMAPS Procedure

This procedure rebuilds the appropriate bitmaps. If no bitmap block DBA is specified, then it rebuilds all bitmaps for the given tablespace.

The procedure cannot be used on the SYSTEM tablespace.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_REBUILD_BITMAPS (
   tablespace_name         IN    VARCHAR2,
   bitmap_relative_file    IN    POSITIVE   DEFAULT NULL,
   bitmap_block            IN    POSITIVE   DEFAULT NULL);

Parameters

Table 99-13 TABLESPACE_REBUILD_BITMAPS Procedure Parameters

Parameter Description
tablespace_name Name of tablespace.
bitmap_relative_file Relative file number of bitmap block to rebuild.
bitmap_block Block number of bitmap block to rebuild.

Usage Notes


Note:

Only full rebuild is supported.

Examples

The following example rebuilds bitmaps for all the files in the USERS tablespace.

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_REBUILD_BITMAPS('USERS'); 

TABLESPACE_REBUILD_QUOTAS Procedure

This procedure rebuilds quotas for the given tablespace.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_REBUILD_QUOTAS (
   tablespace_name         IN    VARCHAR2);

Parameters

Table 99-14 TABLESPACE_REBUILD_QUOTAS Procedure Parameters

Parameter Description
tablespace_name Name of tablespace.

Examples

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_REBUILD_QUOTAS('USERS');

TABLESPACE_RELOCATE_BITMAPS Procedure

Use this procedure to relocate the bitmaps to the destination specified.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_RELOCATE_BITMAPS (
   tablespace_name    IN      VARCHAR2,
   filno              IN      POSITIVE,
   blkno              IN      POSITIVE);

Parameters

Table 99-15 TABLESPACE_RELOCATE_BITMAPS Procedure Parameters

Parameter Name Purpose
tablespace_name Name of Tablespace.
filno Relative File Number of the destination file.
blkno Block Number of the destination dba.

Usage Notes

Migration of a tablespace from dictionary managed to locally managed format could result in the creation of SPACE HEADER segment that contains the bitmap blocks. The SPACE HEADER segment is treated as user data. If the user wishes to explicitly resize a file at or below the space header segment, an error is issued. Use the TABLESPACE_RELOCATE_BITMAPS command to move the control information to a different destination and then resize the file.

This procedure cannot be used on the SYSTEM tablespace.

The tablespace must be kept online and read/write during relocation of bitmaps. This can be done only on migrated locally managed tablespaces.

Examples

EXECUTE  DBMS_SPACE_ADMIN.TABLESPACE_RELOCATE_BITMAPS('TS1', 3, 4);

Moves the bitmaps to file 3, block 4.


Note:

The source and the destination addresses should not overlap. The destination block number is rounded down to the unit boundary. If there is user data in that location an error is raised.


TABLESPACE_VERIFY Procedure

This procedure verifies that the bitmaps and extent maps for the segments in the tablespace are in sync.

Syntax

DBMS_SPACE_ADMIN.TABLESPACE_VERIFY (
   tablespace_name         IN    VARCHAR2,
   verify_option           IN    POSITIVE DEFAULT TABLESPACE_VERIFY_BITMAP);

Parameters

Table 99-16 TABLESPACE_VERIFY Procedure Parameters

Parameter Description
tablespace_name Name of tablespace.
verify_option TABLESPACE_VERIFY_BITMAP.

Examples

EXECUTE DBMS_SPACE_ADMIN.TABLESPACE_VERIFY('USERS');