The DBMS_WORKLOAD_REPOSITORY
package lets you manage the Workload Repository, performing operations such as managing snapshots and baselines.
See Also:
Oracle Database Performance Tuning Guide for more information about the "Automatic Workload Repository"The chapter contains the following topics:
Using DBMS_WORKLOAD_REPOSITORY
Examples
Object Types
Table Types
This section contains topics which relate to using the DBMS_WORKLOAD_REPOSITORY package.
This example shows how to generate an AWR text report with the DBMS_WORKLOAD_REPOSITORY
package for database identifier 1557521192, instance id 1, snapshot ids 5390 and 5391 and with default options.
-- make sure to set line size appropriately -- set linesize 152 SELECT output FROM TABLE( DBMS_WORKLOAD_REPOSITORY.AWR_REPORT_TEXT( 1557521192, 1, 5390, 5392) ) ;
You can call the DBMS_WORKLOAD_REPOSITORY
packaged functions directly as in the example, but Oracle recommends you use the corresponding supplied SQL script (awrrpt.sql
in this case) for the packaged function, which prompts the user for required information.
The DBMS_WORKLOAD_REPOSITORY
package defines an object and associated table types.
This type shows the values of the metrics corresponding to a baseline.
TYPE breakpoint_info AS OBJECT ( baseline_name VARCHAR2(64), dbid NUMBER NOT NULL, instance_number NUMBER NOT NULL, beg_time DATE NOT NULL, end_time DATE NOT NULL, metric_id NUMBER NOT NULL, metric_name VARCHAR2(64) NOT NULL, metric_unit VARCHAR2(64) NOT NULL, num_interval NUMBER NOT NULL, interval_size NUMBER NOT NULL, average NUMBER NOT NULL, minimum NUMBER NOT NULL, maximum NUMBER NOT NULL);
Table 162-1 RUNTIME_INFO Fields
Field | Description |
---|---|
|
Name of the Baseline |
|
Database ID for the snapshot |
instance_number |
Instance number for the snapshot |
|
Begin time of the interval |
|
End time of the interval |
|
Metric ID |
|
Metric name |
|
Unit of measurement |
|
Number of intervals observed |
|
Interval size (in hundredths of a second) |
|
Average over the period |
|
Minimum value observed |
|
Maximum value observed |
Table 162-2 DBMS_WORKLOAD_REPOSITORY Package Subprograms
Subprogram | Description |
---|---|
Adds a colored SQL ID |
|
Displays a global or Oracle Real Application Clusters (Oracle RAC) ASH Spot report in HTML format. |
|
Displays a global or Oracle Real Application Clusters (Oracle RAC) ASH Spot report in Text format. |
|
Displays the ASH report in HTML |
|
Displays the ASH report in text |
|
Displays the AWR Diff-Diff report in HTML |
|
Displays the AWR Diff-Diff report in text |
|
Displays the Global AWR Compare Periods Report in HTML |
|
Displays the Global AWR Compare Periods Report in text |
|
Displays the Global AWR report in HTML |
|
Displays the Global AWR report in text |
|
Displays the AWR report in HTML |
|
Displays the AWR report in text |
|
Configures specified report thresholds, including the number of rows in the report |
|
Displays the AWR SQL Report in HTML format |
|
Displays the AWR SQL Report in text format |
|
Creates a single baseline |
|
Creates a baseline template |
|
Creates a manual snapshot immediately |
|
Drops a range of snapshots |
|
Removes a baseline template that is no longer needed |
|
Activates service |
|
Modifies the snapshot settings |
|
Modifies the window size for the Default Moving Window Baseline |
|
Purges SQL details, specifically rows from |
|
Removes a colored SQL ID |
|
Renames a baseline |
|
Shows the values of the metrics corresponding to a baseline |
|
Updates rows of |
This procedure adds a colored SQL ID. If an SQL ID is colored, it will be captured in every snapshot, independent of its level of activities (so that it does not have to be a TOP
SQL
). Capture occurs if the SQL is found in the cursor cache at snapshot time.To uncolor the SQL, invoke the REMOVE_COLORED_SQL Procedure.
This table function displays a global or Oracle Real Application Clusters (Oracle RAC) ASH Spot report in HTML format.
DBMS_WORKLOAD_REPOSITORY.ASH_GLOBAL_REPORT_HTML( l_dbid IN NUMBER, l_inst_num IN VARCHAR2((1023), l_btime IN DATE, l_etime IN DATE, l_options IN NUMBER DEFAULT 0, l_slot_width IN NUMBER DEFAULT 0, l_sid IN NUMBER DEFAULT NULL, l_sql_id IN VARCHAR2 DEFAULT NULL, l_wait_class IN VARCHAR2 DEFAULT NULL, l_service_hash IN NUMBER DEFAULT NULL, l_module IN VARCHAR2 DEFAULT NULL, l_action IN VARCHAR2 DEFAULT NULL, l_client_id IN VARCHAR2 DEFAULT NULL, l_plsql_entry IN VARCHAR2 DEFAULT NULL, l_data_src IN NUMBER DEFAULT 0) RETURN awrrpt_html_type_table PIPELINED;
Table 162-4 ASH_GLOBAL_REPORT_HTML Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
List of instances (such as |
|
The 'begin time' |
|
The 'end time' |
|
Report level (currently not used) |
|
Specifies (in seconds) how wide the slots used in the "Top Activity" section of the report should be. This argument is optional, and if it is not specified the time interval between |
|
Session ID (see Usage Notes) |
|
SQL ID (see Usage Notes) |
|
Wait class name (see Usage Notes) |
|
Service name hash (see Usage Notes) |
|
Module name (see Usage Notes) |
|
Action name (see Usage Notes) |
|
Client ID for end-to-end backtracing (see Usage Notes) |
|
PL/SQL entry point (see Usage Notes) |
|
Ignored since the report works off of data on disk only |
You can call the function directly but Oracle recommends you use the ashrpti.sql
script which prompts users for the required information.
The unspecified optional arguments are used to generate an ASH Reports that specify 'report targets' such as a SQL statement, or a session, or a particular Service/Module combination. These arguments are specified to restrict the ASH rows that would be used to generate the report. For example, to generate an ASH report on a particular SQL statement, such as SQL_ID 'abcdefghij123
' pass that sql_id
value to the l_sql_id
argument:
l_sql_id => 'abcdefghij123'
Any combination of those optional arguments can be passed in, and only rows in ASH that satisfy all of those 'report targets' will be used. If multiple 'report targets' are specified, AND
conditional logic is used to connect them. For example, to generate an ASH report on MODULE
"PAYROLL
" and ACTION
"PROCESS
", use the following predicate:
l_module => 'PAYROLL', l_action => 'PROCESS'
Valid SQL wildcards can be used in all the arguments that are of type VARCHAR2
.
Table 162-5 ASH_GLOBAL_REPORT_HTML: Wildcards Allowed (or Not) in Arguments
Argument Name | Comment | Wildcard Allowed |
---|---|---|
|
Session ID (for example, |
No |
|
SQL ID (for example, |
Yes |
|
Wait class name (for example, |
Yes |
|
Service name hash (for example, |
No |
|
Module name (for example, |
Yes |
|
Action name (for example, |
Yes |
|
Client ID for end-to-end backtracing (for example, |
Yes |
|
Wildcards are not allowed for |
No |
This table function Displays a global or Oracle Real Application Clusters (Oracle RAC) ASH Spot report in Text format.
DBMS_WORKLOAD_REPOSITORY.ASH_GLOBAL_REPORT_TEXT( l_dbid IN VARCHAR2(1023), l_inst_num IN NUMBER, l_btime IN DATE, l_etime IN DATE, l_options IN NUMBER DEFAULT 0, l_slot_width IN NUMBER DEFAULT 0, l_sid IN NUMBER DEFAULT NULL, l_sql_id IN VARCHAR2 DEFAULT NULL, l_wait_class IN VARCHAR2 DEFAULT NULL, l_service_hash IN NUMBER DEFAULT NULL, l_module IN VARCHAR2 DEFAULT NULL, l_action IN VARCHAR2 DEFAULT NULL, l_client_id IN VARCHAR2 DEFAULT NULL, l_plsql_entry IN VARCHAR2 DEFAULT NULL, l_data_src IN NUMBER DEFAULT 0) RETURN awrrpt_text_type_table PIPELINED;
Table 162-6 ASH_GLOBAL_REPORT_TEXT Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
List of instances (such as |
|
The 'begin time' |
|
The 'end time' |
|
Report level (currently not used) |
|
Specifies (in seconds) how wide the slots used in the "Top Activity" section of the report should be. This argument is optional, and if it is not specified the time interval between |
|
Session ID (see Usage Notes) |
|
SQL ID (see Usage Notes) |
|
Wait class name (see Usage Notes) |
|
Service name hash (see Usage Notes) |
|
Module name (see Usage Notes) |
|
Action name (see Usage Notes) |
|
Client ID for end-to-end backtracing (see Usage Notes) |
|
PL/SQL entry point (see Usage Notes) |
|
Ignored since the report works off of data on disk only |
You can call the function directly but Oracle recommends you use the ashrpti.sql
script which prompts users for the required information.
The unspecified optional arguments are used to generate an ASH Reports that specify 'report targets' such as a SQL statement, or a session, or a particular Service/Module combination. These arguments are specified to restrict the ASH rows that would be used to generate the report. For example, to generate an ASH report on a particular SQL statement, such as SQL_ID 'abcdefghij123
' pass that sql_id value to the l_sql_id
argument:
l_sql_id => 'abcdefghij123'
Table 162-7 ASH_GLOBAL_REPORT_TEXT: Wildcards Allowed (or Not) in Arguments
Argument Name | Comment | Wildcard Allowed |
---|---|---|
|
Session ID (for example, |
No |
|
SQL ID (for example, |
Yes |
|
Wait class name (for example, |
Yes |
|
Service name hash (for example, |
No |
|
Module name (for example, |
Yes |
|
Action name (for example, |
Yes |
|
Client ID for end-to-end backtracing (for example, |
Yes |
|
PL/SQL entry point (for example, " |
Yes |
|
Wildcards are not allowed for |
No |
Any combination of those optional arguments can be passed in, and only rows in ASH that satisfy all of those 'report targets' will be used. If multiple 'report targets' are specified, AND
conditional logic is used to connect them. For example, to generate an ASH report on MODULE
"PAYROLL
" and ACTION
"PROCESS
", use the following predicate:
l_module => 'PAYROLL', l_action => 'PROCESS'
Valid SQL wildcards can be used in all the arguments that are of type VARCHAR2
.
This table function displays the ASH Spot report in HTML.
DBMS_WORKLOAD_REPOSITORY.ASH_REPORT_HTML( l_dbid IN NUMBER, l_inst_num IN NUMBER, l_btime IN DATE, l_etime IN DATE, l_options IN NUMBER DEFAULT 0, l_slot_width IN NUMBER DEFAULT 0, l_sid IN NUMBER DEFAULT NULL, l_sql_id IN VARCHAR2 DEFAULT NULL, l_wait_class IN VARCHAR2 DEFAULT NULL, l_service_hash IN NUMBER DEFAULT NULL, l_module IN VARCHAR2 DEFAULT NULL, l_action IN VARCHAR2 DEFAULT NULL, l_client_id IN VARCHAR2 DEFAULT NULL, l_plsql_entry IN VARCHAR2 DEFAULT NULL, l_data_src IN NUMBER DEFAULT 0) RETURN awrrpt_html_type_table PIPELINED;
Table 162-8 ASH_REPORT_HTML Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
Instance number |
|
The 'begin time' |
|
The 'end time' |
|
Report level (currently not used) |
|
Specifies (in seconds) how wide the slots used in the "Top Activity" section of the report should be. This argument is optional, and if it is not specified the time interval between |
|
Session ID (see Usage Notes) |
|
SQL ID (see Usage Notes) |
|
Wait class name (see Usage Notes) |
|
Service name hash (see Usage Notes) |
|
Module name (see Usage Notes) |
|
Action name (see Usage Notes) |
|
Client ID for end-to-end backtracing (see Usage Notes) |
|
PL/SQL entry point (see Usage Notes) |
|
Can be used to specify a data source (see Usage Notes)
|
You can call the function directly but Oracle recommends you use the ashrpti.sql
script which prompts users for the required information.
The unspecified optional arguments are used to generate an ASH Reports that specify 'report targets' such as a SQL statement, or a session, or a particular Service/Module combination. These arguments are specified to restrict the ASH rows that would be used to generate the report. For example, to generate an ASH report on a particular SQL statement, such as SQL_ID 'abcdefghij123
' pass that sql_id
value to the l_sql_id
argument:
l_sql_id => 'abcdefghij123'
Any combination of those optional arguments can be passed in, and only rows in ASH that satisfy all of those 'report targets' will be used. If multiple 'report targets' are specified, AND
conditional logic is used to connect them. For example, to generate an ASH report on MODULE
"PAYROLL
" and ACTION
"PROCESS
", use the following predicate:
l_module => 'PAYROLL', l_action => 'PROCESS'
Valid SQL wildcards can be used in all the arguments that are of type VARCHAR2
.
Table 162-9 ASH_REPORT_HTML: Wildcards Allowed (or Not) in Arguments
Argument Name | Comment | Wildcard Allowed |
---|---|---|
|
Session ID (for example, |
No |
|
SQL ID (for example, |
Yes |
|
Wait class name (for example, |
Yes |
|
Service name hash (for example, |
No |
|
Module name (for example, |
Yes |
|
Action name (for example, |
Yes |
|
Client ID for end-to-end backtracing (for example, |
Yes |
|
Wildcards are not allowed for |
No |
This table function displays the ASH Spot report in text.
DBMS_WORKLOAD_REPOSITORY.ASH_REPORT_TEXT( l_dbid IN NUMBER, l_inst_num IN NUMBER, l_btime IN DATE, l_etime IN DATE, l_options IN NUMBER DEFAULT 0, l_slot_width IN NUMBER DEFAULT 0, l_sid IN NUMBER DEFAULT NULL, l_sql_id IN VARCHAR2 DEFAULT NULL, l_wait_class IN VARCHAR2 DEFAULT NULL, l_service_hash IN NUMBER DEFAULT NULL, l_module IN VARCHAR2 DEFAULT NULL, l_action IN VARCHAR2 DEFAULT NULL, l_client_id IN VARCHAR2 DEFAULT NULL, l_plsql_entry IN VARCHAR2 DEFAULT NULL, l_data_src IN NUMBER DEFAULT 0) RETURN awrrpt_text_type_table PIPELINED;
Table 162-10 ASH_REPORT_TEXT Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
Instance number |
|
The 'begin time' |
|
The 'end time' |
|
Report level (currently not used) |
|
Specifies (in seconds) how wide the slots used in the "Top Activity" section of the report should be. This argument is optional, and if it is not specified the time interval between |
|
Session ID (see Usage Notes) |
|
SQL ID (see Usage Notes) |
|
Wait class name (see Usage Notes) |
|
Service name hash (see Usage Notes) |
|
Module name (see Usage Notes) |
|
Action name (see Usage Notes) |
|
Client ID for end-to-end backtracing (see Usage Notes) |
|
PL/SQL entry point (see Usage Notes) |
|
Can be used to specify a data source (see Usage Notes)
|
You can call the function directly but Oracle recommends you use the ashrpti.sql
script which prompts users for the required information.
By default, the report uses the begin and end time parameters (l_btime
and l_etime
, respectively) to find all rows in that time range either from memory, or disk, or both. However, using l_data_src
, one can explicitly specify one of those data sources. For example, to generate an ASH report on all rows between l_btime
and l_time
found in memory, use
l_data_src => 1
Similarly, to generate a report on samples found only on disk, use
l_data_src => 2
The unspecified optional arguments are used to generate an ASH Reports that specify 'report targets' such as a SQL statement, or a session, or a particular Service/Module combination. These arguments are specified to restrict the ASH rows that would be used to generate the report. For example, to generate an ASH report on a particular SQL statement, such as SQL_ID 'abcdefghij123
' pass that sql_id value to the l_sql_id
argument:
l_sql_id => 'abcdefghij123'
Table 162-11 ASH_REPORT_TEXT: Wildcards Allowed (or Not) in Arguments
Argument Name | Comment | Wildcard Allowed |
---|---|---|
|
Session ID (for example, |
No |
|
SQL ID (for example, |
Yes |
|
Wait class name (for example, |
Yes |
|
Service name hash (for example, |
No |
|
Module name (for example, |
Yes |
|
Action name (for example, |
Yes |
|
Client ID for end-to-end backtracing (for example, |
Yes |
|
PL/SQL entry point (for example, " |
Yes |
|
Wildcards are not allowed for |
No |
Any combination of those optional arguments can be passed in, and only rows in ASH that satisfy all of those 'report targets' will be used. If multiple 'report targets' are specified, AND
conditional logic is used to connect them. For example, to generate an ASH report on MODULE
"PAYROLL
" and ACTION
"PROCESS
", use the following predicate:
l_module => 'PAYROLL', l_action => 'PROCESS'
Valid SQL wildcards can be used in all the arguments that are of type VARCHAR2
.
This table function displays the AWR Compare Periods report in HTML.
DBMS_WORKLOAD_REPOSITORY.AWR_DIFF_REPORT_HTML( dbid1 IN NUMBER, inst_num1 IN NUMBER, bid1 IN NUMBER, eid1 IN NUMBER, dbid2 IN NUMBER, inst_num2 IN NUMBER, bid2 IN NUMBER, eid2 IN NUMBER) RETURN awrdrpt_text_type_table PIPELINED;
This table function displays the AWR Compare Periods report in text.
DBMS_WORKLOAD_REPOSITORY.AWR_DIFF_REPORT_TEXT( dbid1 IN NUMBER, inst_num1 IN NUMBER, bid1 IN NUMBER, eid1 IN NUMBER, dbid2 IN NUMBER, inst_num2 IN NUMBER, bid2 IN NUMBER, eid2 IN NUMBER) RETURN awrdrpt_text_type_table PIPELINED;
This table function displays Global AWR Compare Periods Report in HTML format.
The first overload accepts comma-separated lists of instance numbers for inst_num1
and inst_num2
. No leading zeroes are allowed and there is a limit of 1023 characters.
DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_DIFF_REPORT_HTML ( dbid1 IN NUMBER, inst_num1 IN AWRRPT_INSTANCE_LIST_TYPE, bid1 IN NUMBER, eid1 IN NUMBER, dbid2 IN NUMBER, inst_num2 IN AWRRPT_INSTANCE_LIST_TYPE, bid2 IN NUMBER, eid2 IN NUMBER) RETURN awrrpt_html_type_table PIPELINED; DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_DIFF_REPORT_HTML ( dbid1 IN NUMBER, inst_num1 IN VARCHAR2, bid1 IN NUMBER, eid1 IN NUMBER, dbid2 IN NUMBER, inst_num2 IN VARCHAR2, bid2 IN NUMBER, eid2 IN NUMBER) RETURN awrrpt_html_type_table PIPELINED;
Table 162-14 AWR_GLOBAL_DIFF_REPORT_HTML Function Parameters
Parameter | Description |
---|---|
|
1st database identifier |
|
1st list of instance numbers. If set to |
bid1 |
1st Begin Snap ID |
|
1st End Snapshot ID |
|
2nd database identifier |
|
2nd list of instance numbers to be included in report. If set to |
bid2 |
2nd Begin Snap ID |
|
2nd End Snapshot ID |
This table function displays Global AWR Compare Periods Report in text format.
The first overload accepts comma-separated lists of instance numbers for inst_num1
and inst_num2
. No leading zeroes are allowed and there is a limit of 1023 characters.
DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_DIFF_REPORT_TEXT ( dbid1 IN NUMBER, inst_num1 IN AWRRPT_INSTANCE_LIST_TYPE, bid1 IN NUMBER, eid1 IN NUMBER, dbid2 IN NUMBER, inst_num2 IN AWRRPT_INSTANCE_LIST_TYPE, bid2 IN NUMBER, eid2 IN NUMBER) RETURN awrdrpt_text_type_table PIPELINED; DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_DIFF_REPORT_TEXT ( dbid1 IN NUMBER, inst_num1 IN VARCHAR2, bid1 IN NUMBER, eid1 IN NUMBER, dbid2 IN NUMBER, inst_num2 IN VARCHAR2, bid2 IN NUMBER, eid2 IN NUMBER) RETURN awrdrpt_text_type_table PIPELINED;
Table 162-15 AWR_GLOBAL_DIFF_REPORT_TEXT Functions Parameters
Parameter | Description |
---|---|
|
1st database identifier |
|
1st list of instance numbers. If set to |
bid1 |
1st Begin Snap ID |
|
1st End Snapshot ID |
|
2nd database identifier |
|
2nd list of instance numbers to be included in report. If set to |
bid2 |
2nd Begin Snap ID |
|
2nd End Snapshot ID |
This table function displays the Global AWR report in HTML.
The first overload accepts a comma-separated list of instance numbers. No leading zeroes are allowed and there is a limit of 1023 characters.
DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_REPORT_HTML ( l_dbid IN NUMBER, l_inst_num IN AWRRPT_INSTANCE_LIST_TYPE, l_bid IN NUMBER, l_eid IN NUMBER, l_options IN NUMBER DEFAULT 0) RETURN awrrpt_html_type_table PIPELINED; DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_REPORT_HTML ( l_dbid IN NUMBER, l_inst_num IN VARCHAR2, l_bid IN NUMBER, l_eid IN NUMBER, l_options IN NUMBER DEFAULT 0) RETURN awrrpt_html_type_table PIPELINED;
Table 162-16 AWR_GLOBAL_REPORT_HTML Function Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
List of instance numbers to be included in report. If set to |
|
Begin Snap ID |
|
End Snapshot ID |
|
Report level (currently not used) |
This table function displays the Global AWR report in text.
The first overload accepts a comma-separated list of instance numbers. No leading zeroes are allowed and there is a limit of 1023 characters
DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_REPORT_TEXT( l_dbid IN NUMBER, l_inst_num IN AWRRPT_INSTANCE_LIST_TYPE, l_bid IN NUMBER, l_eid IN NUMBER, l_options IN NUMBER DEFAULT 0) RETURN awrdrpt_text_type_table PIPELINED; DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_REPORT_TEXT( l_dbid IN NUMBER, l_inst_num IN VARCHAR2, l_bid IN NUMBER, l_eid IN NUMBER, l_options IN NUMBER DEFAULT 0) RETURN awrdrpt_text_type_table PIPELINED;
Table 162-17 AWR_GLOBAL_REPORT_TEXT Function Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
List of instance numbers to be included in report. If set to |
|
Begin Snap ID |
|
End Snapshot ID |
|
A flag to specify to control the output of the report. Currently, not used. |
This table function displays the AWR report in HTML.
DBMS_WORKLOAD_REPOSITORY.AWR_REPORT_HTML( l_dbid IN NUMBER, l_inst_num IN NUMBER, l_bid IN NUMBER, l_eid IN NUMBER, l_options IN NUMBER DEFAULT 0) RETURN awrrpt_text_type_table PIPELINED;
Table 162-18 AWR_REPORT_HTML Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
Instance number |
|
The ' |
|
The ' |
|
A flag to specify to control the output of the report. Currently, Oracle supports one value:
|
This table function displays the AWR report in text.
DBMS_WORKLOAD_REPOSITORY.AWR_REPORT_TEXT( l_dbid IN NUMBER, l_inst_num IN NUMBER, l_bid IN NUMBER, l_eid IN NUMBER, l_options IN NUMBER DEFAULT 0) RETURN awrrpt_text_type_table PIPELINED;
Table 162-19 AWR_REPORT_TEXT Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
Instance number |
|
The ' |
|
The ' |
|
A flag to specify to control the output of the report. Currently, Oracle supports one value:
|
This procedure configure specified report thresholds, including the number of rows in the report.
DBMS_WORKLOAD_REPOSITORY.AWR_SET_REPORT_THRESHOLDS( top_n_events IN NUMBER DEFAULT NULL, top_n_files IN NUMBER DEFAULT NULL, top_n_segments IN NUMBER DEFAULT NULL, top_n_services IN NUMBER DEFAULT NULL, top_n_sql IN NUMBER DEFAULT NULL, top_n_sql_max IN NUMBER DEFAULT NULL, top_sql_pct IN NUMBER DEFAULT NULL, shmem_threshold IN NUMBER DEFAULT NULL, versions_threshold IN NUMBER DEFAULT NULL);
Table 162-20 AWR_SET_REPORT_THRESHOLDS Procedure Parameters
Parameter | Description |
---|---|
|
Number of most significant wait events to be included |
|
Number of most active files to be included |
|
Number of most active segments to be included |
|
Number of most active services to be included |
|
Number of most significant SQL statements to be included |
|
Number of SQL statements to be included if their activity is greater than that specified by |
|
Significance threshold for SQL statements between |
|
Shared memory low threshold |
|
Plan version count low threshold. |
The effect of each setting depends on the type of report being generated as well as on the underlying AWR data. Not all settings are meaningful for each report type. Invalid settings (such as negative numbers) are ignored.
Settings are effective only in the context of the session that executes the AWR_SET_REPORT_THRESHOLDS
procedure. For example, to get a report that lists top 12 segments as compared to the default, one can invoke as follows:
DBMS_WORKLOAD_REPOSITORY.AWR_SET_REPORT_THRESHOLDS (top_n_segments=>12);
This table function displays the AWR SQL Report in HTML format.
DBMS_WORKLOAD_REPOSITORY.AWR_SQL_REPORT_HTML( l_dbid IN NUMBER, l_inst_num IN NUMBER, l_bid IN NUMBER, l_eid IN NUMBER, l_sqlid IN VARCHAR2, l_options IN NUMBER DEFAULT 0) RETURN awrrpt_html_type_table PIPELINED;
Table 162-21 AWR_SQL_REPORT_HTML Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
Instance number |
|
The ' |
|
The ' |
|
SQL ID of statement to be analyzed |
|
A flag to specify to control the output of the report. Currently, not used. |
This table function displays the AWR SQL Report in text format.
DBMS_WORKLOAD_REPOSITORY.AWR_SQL_REPORT_TEXT( l_dbid IN NUMBER, l_inst_num IN NUMBER, l_bid IN NUMBER, l_eid IN NUMBER, l_sqlid IN VARCHAR2, l_options IN NUMBER DEFAULT 0) RETURN awrrpt_text_type_table PIPELINED;
Table 162-22 AWR_SQL_REPORT_TEXT Parameters
Parameter | Description |
---|---|
|
Database identifier |
|
Instance number |
|
The ' |
|
The ' |
|
SQL ID of statement to be analyzed |
|
Flag to specify to control the output of the report. Currently, not used. |
This function and procedure creates a baseline.
DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE( start_snap_id IN NUMBER, end_snap_id IN NUMBER, baseline_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL, expiration IN NUMBER DEFAULT NULL); DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE( start_snap_id IN NUMBER, end_snap_id IN NUMBER, baseline_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL, expiration IN NUMBER DEFAULT NULL) RETURN NUMBER; DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE( start_time IN DATE, end_time IN DATE, baseline_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL, expiration IN NUMBER DEFAULT NULL); DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE( start_time IN DATE, end_time IN DATE, baseline_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL, expiration IN NUMBER DEFAULT NULL); RETURN NUMBER;
Table 162-23 CREATE_BASELINE Function & Procedure Parameters
Parameter | Description |
---|---|
|
Start snapshot sequence number for the baseline' |
|
End snapshot sequence number for the baseline |
|
Start time for the baseline' |
|
End time for the baseline |
|
Name of baseline. |
|
Database Identifier for baseline. If |
|
Expiration in number of days for the baseline. If |
An error will be returned if this baseline name already exists in the system.
The snapshot range that is specified for this interface must be an existing pair of snapshots in the database. An error will be returned if the inputted snapshots do not exist in the system.
This example creates a baseline (named 'oltp_peakload_bl
') between snapshots 105 and 107 for the local database:
EXECUTE DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE (start_snap_id => 105, end_snap_id => 107, baseline_name => 'oltp_peakload_bl');
If you query the DBA_HIST_BASELINE
view after the CREATE
BASELINE
action, you will see the newly created baseline in the Workload Repository.
This procedure specifies a template for how they would like baselines to be created for future time periods.
Specifies a template for generating a baseline for a single time period in the future.
DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE_TEMPLATE( start_time IN DATE, end_time IN DATE, baseline_name IN VARCHAR2, template_name IN VARCHAR2, expiration IN NUMBER, dbid IN NUMBER DEFAULT NULL);
Specifies a template for creating and dropping baseline based on repeating time periods:
DBMS_WORKLOAD_REPOSITORY.CREATE_BASELINE_TEMPLATE( day_of_week IN VARCHAR2, hour_in_day IN NUMBER, duration IN NUMBER, start_time IN DATE, end_time IN DATE, baseline_name_prefix IN VARCHAR2, template_name IN VARCHAR2, expiration IN NUMBER, dbid IN NUMBER DEFAULT NULL);
Table 162-24 CREATE_BASELINE_TEMPLATE Procedure Parameters
Parameter | Description |
---|---|
|
Start Time for the baseline to be created' |
|
End Time for the baseline to be created |
|
Name of baseline to be created |
|
Name for the template |
|
Expiration in number of days for the baseline. If |
|
Database Identifier for baseline. If |
|
Day of week that the baseline should repeat on. Specify one of the following values: |
|
Value of 0-23 to specify the Hour in the Day the baseline should start |
|
Duration (in number of hours) after hour in the day that the baseline should last |
|
Name for baseline prefix. When creating the baseline, the name of the baseline will be the prefix appended with the date information. |
This function and procedure create snapshots. In the case of the function, the snapshot ID is returned.
DBMS_WORKLOAD_REPOSITORY.CREATE_SNAPSHOT( flush_level IN VARCHAR2 DEFAULT 'TYPICAL'); DBMS_WORKLOAD_REPOSITORY.CREATE_SNAPSHOT( flush_level IN VARCHAR2 DEFAULT 'TYPICAL') RETURN NUMBER;
This procedure drops a baseline.
DBMS_WORKLOAD_REPOSITORY.DROP_BASELINE( baseline_name IN VARCHAR2, cascade IN BOOLEAN DEFAULT FALSE, dbid IN NUMBER DEFAULT NULL);
Table 162-26 DROP_BASELINE Parameters
Parameter | Description |
---|---|
|
Name of baseline to drop from the system |
|
If |
|
Database Identifier for baseline. If |
This example drops the baseline 'oltp_peakload_bl
' without dropping the underlying snapshots:
EXECUTE DBMS_WORKLOAD_REPOSITORY.DROP_BASELINE ( baseline_name => 'oltp_peakload_bl');
If you query the DBA_HIST_BASELINE
view after the DROP_BASELINE
action, you will see the specified baseline definition is removed. You can query the DBA_HIST_SNAPSHOT
view to find that the underlying snapshots are left intact.
This procedure removes a template that is no longer needed.
DBMS_WORKLOAD_REPOSITORY.DROP_BASELINE_TEMPLATE( template_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL);
This procedure drops a range of snapshots.
DBMS_WORKLOAD_REPOSITORY.DROP_SNAPSHOT_RANGE( low_snap_id IN NUMBER, high_snap_id IN NUMBER dbid IN NUMBER DEFAULT NULL);
This example drops the range of snapshots between snapshot id 102 to 105 for the local database:
EXECUTE DBMS_WORKLOAD_REPOSITORY.DROP_SNAPSHOT_RANGE(102, 105);
If you query the dba_hist_snapshot
view after the Drop Snapshot
action, you will see that snapshots 102 to 105 are removed from the Workload Repository.
This procedure controls three aspects of snapshot generation.
The INTERVAL
setting affects how often snapshots are automatically captured.
The RETENTION
setting affects how long snapshots are retained in the Workload Repository.
The number of SQL captured for each Top criteria. If the user manually specifies a value for Top N SQL, the AWR SQL collection will use the user-specified number for both automatic and manual snapshots.
There are two overloads. The first takes a NUMBER
and the second takes a VARCHAR2
for the topnsql
argument. The differences are described under the Parameters description.
DBMS_WORKLOAD_REPOSITORY.MODIFY_SNAPSHOT_SETTINGS( retention IN NUMBER DEFAULT NULL, interval IN NUMBER DEFAULT NULL, topnsql IN NUMBER DEFAULT NULL, dbid IN NUMBER DEFAULT NULL); DBMS_WORKLOAD_REPOSITORY.MODIFY_SNAPSHOT_SETTINGS( retention IN NUMBER DEFAULT NULL, interval IN NUMBER DEFAULT NULL, topnsql IN VARCHAR2, dbid IN NUMBER DEFAULT NULL);
Table 162-29 MODIFY_SNAPSHOT_SETTINGS Procedure Parameters
Parameter | Description |
---|---|
|
New retention time (in minutes). The specified value must be in the range of If If NOTE: The retention setting must be greater than or equal to the window size of the ' |
|
New interval setting between each snapshot, in units of minutes. The specified value must be in the range If If |
|
|
|
Database identifier in AWR for which to modify the snapshot settings. If |
This example changes the interval
setting to one hour and the retention
setting to two weeks for the local database:
EXECUTE DBMS_WORKLOAD_REPOSITORY.MODIFY_SNAPSHOT_SETTINGS( interval => 60, retention => 20160);
If you query the DBA_HIST_WR_CONTROL
table after this procedure is executed, you will see the changes to these settings.
This procedure modifies the window size for the Default Moving Window Baseline.
DBMS_WORKLOAD_REPOSITORY.MODIFY_BASELINE_WINDOW_SIZE( window_size IN NUMBER, dbid IN NUMBER DEFAULT NULL);
The window size must be less than or equal to the AWR retention setting. If the window size needs to be greater than the retention setting, the MODIFY_SNAPSHOT_SETTINGS Procedures can be used to adjust the retention setting. A moving window can be set to a maximum of 13 weeks.
This procedure purges SQL details, specifically rows from WRH$_SQLTEXT
and WRH$_SQL_PLAN
that do not have corresponding rows (DBID, SQL_ID) in WRH$_SQLSTAT
.
The subprogram calls for the DBID for which to run the purge. If the DBID is not specified, the database DBID is used. You can constrain runtime by specifying the maximum number of rows to purge per table. If no maximum is specified, the subprograms tries to purge all applicable rows.
DBMS_WORKLOAD_REPOSITORY.PURGE_SQL_DETAILS( numrows IN NUMBER DEFAULT NULL, dbid IN NUMBER DEFAULT NULL) IS EXTERNAL NAME "kewrpsd_purge_sql_details" WITH CONTEXT PARAMETERS( context, numrows OCINUMBER, numrows indicator sb4, dbid OCINUMBER, dbid indicator sb4) LIBRARY DBMS_SWRF_LIB;
This procedure removes a colored SQL ID. After a SQL is uncolored, it will no longer be captured in a snapshot automatically, unless it makes the TOP
list.
This procedure renames a baseline.
DBMS_WORKLOAD_REPOSITORY.RENAME_BASELINE( old_baseline_name IN VARCHAR2, new_baseline_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL);
This table function shows the values of the metrics corresponding to a baseline. The table function will return an object of the AWR_BASELINE_METRIC_TYPE Object Type.
DBMS_WORKLOAD_REPOSITORY.SELECT_BASELINE_METRIC( baseline_name IN VARCHAR2, dbid IN NUMBER DEFAULT NULL, instance_num IN NUMBER DEFAULT NULL) RETURN awr_baseline_metric_type_table PIPELINED;
Table 162-34 SELECT_BASELINE_METRIC Function Parameters
Parameter | Description |
---|---|
|
Name of the baseline for which we would like to view metrics |
|
Database Identifier for baseline. If |
|
Instance for which number the user wants to see statistics. If |
This procedure updates rows of WRH$_SEG_STAT_OBJ
table that represent objects in the local database. It attempts to determine the current names for all object belonging to the local database, except those with 'MISSING'
and/or 'TRANSIENT'
values in the name columns. The amount of work performed at each invocation of this routine may be controlled by setting the input parameter.