DBMS_UTILITY v11
The DBMS_UTILITY
package provides support for the following various utility programs:
Function/Procedure | Function or Procedure | Return Type | Description |
---|---|---|---|
ANALYZE_DATABASE(method [, estimate_rows [, estimate_percent [, method_opt ]]]) | Procedure | n/a | Analyze database tables. |
ANALYZE_PART_OBJECT(schema, object_name [, object_type [, command_type [, command_opt [, sample_clause ]]]]) | Procedure | n/a | Analyze a partitioned table. |
ANALYZE_SCHEMA(schema, method [, estimate_rows [, estimate_percent [, method_opt ]]]) | Procedure | n/a | Analyze schema tables. |
CANONICALIZE(name, canon_name OUT, canon_len) | Procedure | n/a | Canonicalizes a string – e.g., strips off white space. |
COMMA_TO_TABLE(list, tablen OUT, tab OUT) | Procedure | n/a | Convert a comma-delimited list of names to a table of names. |
DB_VERSION(version OUT, compatibility OUT) | Procedure | n/a | Get the database version. |
EXEC_DDL_STATEMENT (parse_string) | Procedure | n/a | Execute a DDL statement. |
FORMAT_CALL_STACK | Function | TEXT | Formats the current call stack. |
GET_CPU_TIME | Function | NUMBER | Get the current CPU time. |
GET_DEPENDENCY(type, schema, name) | Procedure | n/a | Get objects that are dependent upon the given object.. |
GET_HASH_VALUE(name, base, hash_size) | Function | NUMBER | Compute a hash value. |
GET_PARAMETER_VALUE(parnam, intval OUT, strval OUT) | Procedure | BINARY_INTEGER | Get database initialization parameter settings. |
GET_TIME | Function | NUMBER | Get the current time. |
NAME_TOKENIZE(name, a OUT, b OUT, c OUT, dblink OUT, nextpos OUT) | Procedure | n/a | Parse the given name into its component parts. |
TABLE_TO_COMMA(tab, tablen OUT, list OUT) | Procedure | n/a | Convert a table of names to a comma-delimited list. |
Advanced Server's implementation of DBMS_UTILITY
is a partial implementation when compared to Oracle's version. Only those functions and procedures listed in the table above are supported.
The following table lists the public variables available in the DBMS_UTILITY
package.
Public Variables | Data Type | Value | Description |
---|---|---|---|
inv_error_on_restrictions | PLS_INTEGER | 1 | Used by the INVALIDATE procedure. |
lname_array | TABLE | For lists of long names. | |
uncl_array | TABLE | For lists of users and names. |
LNAME_ARRAY
The LNAME_ARRAY
is for storing lists of long names including fully-qualified names.
UNCL_ARRAY
The UNCL_ARRAY
is for storing lists of users and names.
ANALYZE_DATABASE, ANALYZE SCHEMA and ANALYZE PART_OBJECT
The ANALYZE_DATABASE(), ANALYZE_SCHEMA() and ANALYZE_PART_OBJECT()
procedures provide the capability to gather statistics on tables in the database. When you execute the ANALYZE
statement, Postgres samples the data in a table and records distribution statistics in the pg_statistics system
table.
ANALYZE_DATABASE, ANALYZE_SCHEMA
, and ANALYZE_PART_OBJECT
differ primarily in the number of tables that are processed:
ANALYZE_DATABASE
analyzes all tables in all schemas within the current database.ANALYZE_SCHEMA
analyzes all tables in a given schema (within the current database).ANALYZE_PART_OBJECT
analyzes a single table.
The syntax for the ANALYZE
commands are:
Parameters - ANALYZE_DATABASE
and ANALYZE_SCHEMA
method
method determines whether the ANALYZE
procedure populates the pg_statistics
table or removes entries from the pg_statistics
table. If you specify a method of DELETE
, the ANALYZE
procedure removes the relevant rows from pg_statistics
. If you specify a method of COMPUTE
or ESTIMATE
, the ANALYZE
procedure analyzes a table (or multiple tables) and records the distribution information in pg_statistics
. There is no difference between COMPUTE
and ESTIMATE
; both methods execute the Postgres ANALYZE
statement. All other parameters are validated and then ignored.
estimate_rows
Number of rows upon which to base estimated statistics. One of estimate_rows
or estimate_percent
must be specified if method is ESTIMATE
.
This argument is ignored, but is included for compatibility.
estimate_percent
Percentage of rows upon which to base estimated statistics. One of estimate_rows
or estimate_percent
must be specified if method is ESTIMATE
.
This argument is ignored, but is included for compatibility.
method_opt
Object types to be analyzed. Any combination of the following:
This argument is ignored, but is included for compatibility.
Parameters - ANALYZE_PART_OBJECT
schema
Name of the schema whose objects are to be analyzed.
object_name
Name of the partitioned object to be analyzed.
object_type
Type of object to be analyzed. Valid values are: T
– table, I
– index.
This argument is ignored, but is included for compatibility.
command_type
Type of analyze functionality to perform. Valid values are: E
- gather estimated statistics based upon on a specified number of rows or a percentage of rows in the sample_clause
clause; C
- compute exact statistics; or V
– validate the structure and integrity of the partitions.
This argument is ignored, but is included for compatibility.
command_opt
For command_type
C
or E
, can be any combination of:
For command_type V
, can be CASCADE
if object_type
is T
.
This argument is ignored, but is included for compatibility.
sample_clause
If command_type
is E
, contains the following clause to specify the number of rows or percentage or rows on which to base the estimate.
SAMPLE n { ROWS | PERCENT }
This argument is ignored, but is included for compatibility.
CANONICALIZE
The CANONICALIZE
procedure performs the following operations on an input string:
- If the string is not double-quoted, verifies that it uses the characters of a legal identifier. If not, an exception is thrown. If the string is double-quoted, all characters are allowed.
- If the string is not double-quoted and does not contain periods, uppercases all alphabetic characters and eliminates leading and trailing spaces.
- If the string is double-quoted and does not contain periods, strips off the double quotes.
- If the string contains periods and no portion of the string is double-quoted, uppercases each portion of the string and encloses each portion in double quotes.
- If the string contains periods and portions of the string are double-quoted, returns the double-quoted portions unchanged including the double quotes and returns the non-double-quoted portions uppercased and enclosed in double quotes.