38 DBMS_COMPRESSION
The DBMS_COMPRESSION
package provides an interface to facilitate choosing the correct compression level for an application.
This chapter contains the following topics:
38.1 DBMS_COMPRESSION Overview
The DBMS_COMPRESSION
package gathers compression-related information within a database environment. This includes tools for estimating compressibility of a table for both partitioned and non-partitioned tables, and gathering row-level compression information on previously compressed tables. This gives the user with adequate information to make compression-related decision.
38.2 DBMS_COMPRESSION Security Model
The DBMS_COMPRESSSION
package is defined with AUTHID CURRENT USER
, so it executes with the privileges of the current user.
38.3 DBMS_COMPRESSION Constants
The DBMS_COMPRESSION
package uses constants that can be used for specifying parameter values.
These constants are shown in the following table:
Table 38-1 DBMS_COMPRESSION Constants - Compression Types
Constant | Type | Value | Description |
---|---|---|---|
|
|
|
No compression |
|
|
|
Advanced row compression |
|
|
|
High for query warehouse compression (Hybrid Columnar Compression) |
|
|
|
Low for query warehouse compression (Hybrid Columnar Compression) |
|
|
|
High archive compression (Hybrid Columnar Compression) |
|
|
|
Low archive compression (Hybrid Columnar Compression) |
|
|
|
Compressed block |
|
|
|
High compression level for LOB operations |
|
|
|
Medium compression level for LOB operations |
|
|
|
Low compression level for LOB operations |
|
|
|
High compression level for indexes |
|
|
|
Low compression level for indexes |
|
|
|
Minimum required number of LOBs in the object for which LOB compression ratio is to be estimated |
|
|
|
Basic table compression |
|
|
|
Maximum number of LOBs used to compute the LOB compression ratio |
|
|
|
In-Memory with no compression |
|
|
|
In-Memory compression level for DML |
|
|
|
In-Memory compression level optimized for query performance |
|
|
|
In-Memory compression level optimized on query performance as well as space saving |
|
|
|
In-Memory low compression level optimizing for capacity |
|
|
|
In-Memory high compression level optimizing for capacity |
|
|
|
Minimum required number of rows in the object for which HCC ratio is to be estimated |
|
|
|
To indicate the use of all the rows in the object to estimate HCC ratio |
|
|
|
Identifies the object whose compression ratio is estimated as of type table |
|
|
2 |
Identifies the object whose compression ratio is estimated as of type index |
Note:
Hybrid columnar compression is a feature of certain Oracle storage systems. See Oracle Database Concepts for more information.
38.4 DBMS_COMPRESSION Data Structures
The DBMS_COMPRESSION
package defines a RECORD
type and a TABLE
type.
RECORD TYPES
TABLE TYPES
38.4.1 COMPREC Record Type
The COMPREC record type is a record for calculating an individual index compression ratio on a table.
Syntax
TYPE COMPREC IS RECORD( ownname varchar2(255), objname varchar2(255), blkcnt_cmp PLS_INTEGER, blkcnt_uncmp PLS_INTEGER, row_cmp PLS_INTEGER, row_uncmp PLS_INTEGER, cmp_ratio NUMBER, objtype PLS_INTEGER);
Fields
Table 38-2 COMPREC Attributes
Field | Description |
---|---|
|
Schema of the object owner |
|
Name of the object |
|
Number of blocks used by the compressed sample of the object |
|
Number of blocks used by the uncompressed sample of the object |
|
Number of rows in a block in compressed sample of the object |
|
Number of rows in a block in uncompressed sample of the object |
|
Compression ratio, |
|
Type of the object |
38.5 Summary of DBMS_COMPRESSION Subprograms
The DBMS_COMPRESSION
package uses the GET_COMPRESSION_RATIO
Procedure and GET_COMPRESSION_TYPE
Function subprograms.
Table 38-3 DBMS_COMPRESSION Package Subprograms
Subprogram | Description |
---|---|
Analyzes the compression ratio of a table, and gives information about compressibility of a table |
|
Returns the compression type for a specified row |
38.5.1 GET_COMPRESSION_RATIO Procedure
This procedure analyzes the compression ratio of a table or an index, and gives information about compressibility of the object. Various parameters can be provided by the user to selectively analyze different compression types.
Syntax
Get compression ratio for an object (table or index, default is table):
DBMS_COMPRESSION.GET_COMPRESSION_RATIO ( scratchtbsname IN VARCHAR2, ownname IN VARCHAR2, objname IN VARCHAR2, subobjname IN VARCHAR2, comptype IN NUMBER, blkcnt_cmp OUT PLS_INTEGER, blkcnt_uncmp OUT PLS_INTEGER, row_cmp OUT PLS_INTEGER, row_uncmp OUT PLS_INTEGER, cmp_ratio OUT NUMBER, comptype_str OUT VARCHAR2, subset_numrows IN NUMBER DEFAULT COMP_RATIO_MINROWS, objtype IN PLS_INTEGER DEFAULT OBJTYPE_TABLE);
Get compression ratio for LOBs:
DBMS_COMPRESSION.GET_COMPRESSION_RATIO ( scratchtbsname IN VARCHAR2, tabowner IN VARCHAR2, tabname IN VARCHAR2, lobname IN VARCHAR2, partname IN VARCHAR2, comptype IN NUMBER, blkcnt_cmp OUT PLS_INTEGER, blkcnt_uncmp OUT PLS_INTEGER, lobcnt OUT PLS_INTEGER, cmp_ratio OUT NUMBER, comptype_str OUT VARCHAR2, subset_numrows IN number DEFAULT COMP_RATIO_LOB_MAXROWS);
Get compression ratio for all indexes on a table. The compression ratios are returned as a collection.
DBMS_COMPRESSION.GET_COMPRESSION_RATIO ( scratchtbsname IN VARCHAR2, ownname IN VARCHAR2, tabname IN VARCHAR2, comptype IN NUMBER, index_cr OUT DBMS_COMPRESSION.COMPRECLIST, comptype_str OUT VARCHAR2, subset_numrows IN NUMBER DEFAULT COMP_RATIO_INDEX_MINROWS);
Parameters
Table 38-4 GET_COMPRESSION_RATIO Procedure Parameters
Parameter | Description |
---|---|
|
Temporary scratch tablespace that can be used for analysis |
|
Schema of the table to analyze |
|
Name of the table to analyze |
|
Name of the object |
|
Name of the partition or sub-partition of the object |
|
Compression types for which analysis should be performed When the object is an index, only the following compression types are valid: Note: The following compression types cannot be specified in this parameter for any type of object: |
|
Number of blocks used by compressed sample of the table |
|
Number of blocks used by uncompressed sample of the table |
|
Number of rows in a block in compressed sample of the table |
|
Number of rows in a block in uncompressed sample of the table |
|
Compression ratio, |
|
String describing the compression type |
|
Number of rows sampled to estimate compression ratio. |
|
Type of the object, either |
|
Name of the LOB column |
|
In case of partitioned tables, the related partition name |
|
Number of lobs actually sampled to estimate compression ratio |
|
List of indexes and their estimated compression ratios |
Usage Notes
The procedure creates different tables in the scratch tablespace and runs analysis on these objects. It does not modify anything in the user-specified tables.
38.5.2 GET_COMPRESSION_TYPE Function
This function returns the compression type for a specified row. If the row is chained, the function returns the compression type of the head piece only, and does not examine the intermediate or the tail piece since head pieces can be differently compressed.
Syntax
DBMS_COMPRESSION.GET_COMPRESSION_TYPE ( ownname IN VARCHAR2, tabname IN VARCHAR2, row_id IN ROWID, subobjname IN VARCHAR2 DEFAULT NULL)) RETURN NUMBER;
Parameters
Table 38-5 GET_COMPRESSION_TYPE Function Parameters
Parameter | Description |
---|---|
|
Schema name of the table |
|
Name of table |
|
Rowid of the row |
|
Name of the table partition or subpartition |
Return Values
Flag to indicate the compression type (see Table 38-1).