32 DBMS_AUTO_INDEX
The DBMS_AUTO_INDEX
package provides the interface for managing auto indexes in an Oracle database.
This chapter contains the following topics:
32.1 DBMS_AUTO_INDEX Overview
The DBMS_AUTO_INDEX
package is the interface for configuring auto indexes and generating reports of auto indexing operations in an Oracle database.
32.2 Summary of DBMS_AUTO_INDEX Subprograms
This table lists the DBMS_AUTO_INDEX
package subprograms and briefly describes them.
Table 32-1 DBMS_AUTO_INDEX Package Subprograms
Procedure | Description |
---|---|
Configures settings related to automatic indexing. |
|
DROP_AUTO_INDEXES Procedure |
This procedure can be used to manually drop the automatically created indexes that overrides the retention parameter setting. |
Deletes all the indexes, except the ones used for constraints, from a schema or a table. |
|
Returns a report of the automatic indexing operations executed during a specific period in a database. |
|
Returns a report of the last automatic indexing operation executed in a database. |
32.2.1 CONFIGURE Procedure
This procedure configures settings related to automatic indexing.
Syntax
DBMS_AUTO_INDEX.CONFIGURE (
parameter_name IN VARCHAR2,
parameter_value IN VARCHAR2,
allow IN BOOLEAN DEFAULT TRUE);
Parameters
Table 32-2 CONFIGURE Procedure Parameters
Parameter | Description |
---|---|
|
Automatic indexing configuration setting. It can have one of the following values:
|
|
Value for the configuration setting specified in When it is set to |
|
This parameter is applicable only for the
Refer to the description of the |
Examples
These examples are based on the assumption that the inclusion list and the exclusion list are initially empty.
The following example adds the SH
and HR
schemas to the exclusion list, so that only the SH
and HR
schemas cannot use auto indexes.
begin dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_SCHEMA', parameter_value => 'SH', allow => FALSE); dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_SCHEMA', parameter_value => 'HR', allow => FALSE); end;
The following example removes the HR
schema from the exclusion list, so that it can also use auto indexes. Now, only the SH
schema cannot use auto indexes, because it is the only schema added to the exclusion list.
begin dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_SCHEMA', parameter_value => 'HR', allow => NULL); end;
The following example removes all the schemas from the exclusion list, so that all the schemas can use auto indexes.
begin dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_SCHEMA', parameter_value => NULL, allow => TRUE); end;
The following example adds the HR
schema to the inclusion list, so that only the HR
schema can use auto indexes.
begin dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_SCHEMA', parameter_value => 'HR', allow => TRUE); end;
The following example sets the retention period for auto indexes to 90 days.
begin dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_RETENTION_FOR_AUTO', parameter_value => '90'); end;
The following example sets the retention period for auto indexes to the default value of 373 days.
begin dbms_auto_index.configure( parameter_name => 'AUTO_INDEX_RETENTION_FOR_AUTO', parameter_value => NULL); end;
The following example enables a table:
EXEC DBMS_AUTO_INDEX.CONFIGURE('AUTO_INDEX_TABLE', 'SH.SALES', TRUE);
To remove all tables from inclusion/exclusion list:
EXEC DBMS_AUTO_INDEX.CONFIGURE('AUTO_INDEX_TABLE', NULL);
32.2.2 DROP_AUTO_INDEXES Procedure
This procedure can be used to manually drop the automatically created indexes that overrides the retention parameter setting.
Syntax
DBMS_AUTO_INDEX.DROP_AUTO_INDEXES (
owner IN VARCHAR2 DEFAULT NULL,
index_name IN VARCHAR2 DEFAULT NULL,
allow_recreate IN BOOLEAN DEFAULT FALSE);
Parameters
Table 32-3 DROP_AUTO_INDEXES Procedure Parameters
Parameter | Description |
---|---|
|
The name of the index owner. |
|
The name of the index. |
allow_recreate |
Set this parameter to allow or disallow automatic creation of the dropped index again. |
Examples
Drop a single index and allow recreate:
exec dbms_auto_index.drop_auto_indexes('SH','"SYS_AI_612ud3j5ngf0c"',TRUE);
Drop all indexes owned by SH and allow recreate:
exec dbms_auto_index.drop_auto_indexes('SH',NULL,TRUE);
Drop all indexes owned by HR, disallowing recreate and then change the recreation status back to allow:
exec dbms_auto_index.drop_auto_indexes('HR',NULL); exec dbms_auto_index.drop_auto_indexes('HR', NULL, TRUE);
Usage Notes
- If the values of the parameters owner and index_name are explicitly set to
NULL
, all auto indexes which the user has privileges on will be dropped. - If owner is explicitly specified and
index_name
is set toNULL
, all auto indexes within the given schema will be dropped. The dropped indexes are not recreated automatically by the system by default. Setallow_recreate
parameter toTRUE
to change this behavior. - This procedure updates the
allow_recreate
status associated with the dropped indexes fromFALSE
toTRUE
and vice-versa.
32.2.3 DROP_SECONDARY_INDEXES Procedure
This procedure deletes all the indexes, except the ones used for constraints, from a schema or a table.
Syntax
DBMS_AUTO_INDEX.DROP_SECONDARY_INDEXES (
ownname IN VARCHAR2 DEFAULT NULL,
tabname IN VARCHAR2 DEFAULT NULL);
Parameters
Table 32-4 DROP_SECONDARY_INDEXES Procedure Parameters
Parameter | Description |
---|---|
|
(Optional) Name of the schema from which all the indexes need to be deleted. Note: The indexes used for constraints are not deleted. |
|
(Optional) Name of the table from which all the indexes need to be deleted. Note: The indexes used for constraints are not deleted. |
Examples
The following example deletes all the indexes, except the ones used for constraints, from the SH
schema.
begin dbms_auto_index.drop_secondary_indexes('SH'); end;
The following example deletes all the indexes, except the ones used for constraints, from the EMP
table in the HR
schema.
begin dbms_auto_index.drop_secondary_indexes('HR', 'EMP'); end;
The following example deletes all the indexes, except the ones used for constraints, for which the user has the delete privileges from all the schemas in a database.
begin dbms_auto_index.drop_secondary_indexes; end;
32.2.4 REPORT_ACTIVITY Function
This function returns a report of the automatic indexing operations executed during a specific period in a database.
Syntax
DBMS_AUTO_INDEX.REPORT_ACTIVITY (
activity_start IN TIMESTAMP WITH TIME ZONE DEFAULT SYSTIMESTAMP - 1,
activity_end IN TIMESTAMP WITH TIME ZONE DEFAULT SYSTIMESTAMP,
type IN VARCHAR2 DEFAULT 'TEXT',
section IN VARCHAR2 DEFAULT 'ALL',
level IN VARCHAR2 DEFAULT 'TYPICAL')
RETURN CLOB;
Parameters
Table 32-5 REPORT_ACTIVITY Function Parameters
Parameter | Description |
---|---|
|
Time starting from which the executed automatic indexing operations are considered for the report. If |
|
Time till which the executed automatic indexing operations are considered for the report. If no value is specified, then the current time is considered as the end time. |
|
Format of the report. It can have one of the following values:
The default value is |
|
Sections to include in the report. It can have a combination of the following values:
A combination of these values can be specified using the
|
|
Level of automatic indexing information to include in the report. It can have one of the following values:
|
Return Value
A report of the automatic indexing operations executed during the specified period in a database.
Examples
The following example generates a typical report of the automatic indexing operations executed in the last 24 hours. The report is generated in the text format and contains all the sections (summary details, auto index details, auto index verification details, and error details).
declare report clob := null; begin report := dbms_auto_index.report_activity(); end;
32.2.5 REPORT_LAST_ACTIVITY Function
This function returns a report of the last automatic indexing operation executed in a database.
Syntax
DBMS_AUTO_INDEX.REPORT_LAST_ACTIVITY (
type IN VARCHAR2 DEFAULT 'TEXT',
section IN VARCHAR2 DEFAULT 'ALL',
level IN VARCHAR2 DEFAULT 'TYPICAL')
RETURN CLOB;
Parameters
Table 32-6 REPORT_LAST_ACTIVITY Function Parameters
Parameter | Description |
---|---|
|
Format of the report. It can have one of the following values:
The default value is |
|
Sections to include in the report. It can have a combination of the following values:
A combination of these values can be specified using the
|
|
Level of automatic indexing information to include in the report. It can have one of the following values:
|
Return Value
A report of the last automatic indexing operation executed in a database.
Examples
The following example generates a typical report of the last automatic indexing operation executed in a database. The report is generated in the text format and contains all the sections (summary details, auto index details, auto index verification details, and error details).
declare report clob := null; begin report := dbms_auto_index.report_last_activity(); end;