Oracle DBMS_ADDM
Version 23c

General Information
Library Note Morgan's Library Page Header
ACE Director Alum Daniel Morgan, founder of Morgan's Library, is scheduling complimentary technical Workshops on Database Security for the first 30 Oracle Database customers located anywhere in North America, EMEA, LATAM, or APAC that send an email to asra_us@oracle.com. Request a Workshop for your organization today.
Purpose Create and execute an tasks to analyze all instances of a database.
AUTHID CURRENT_USER
Dependencies
CDB_ADDM_PENDING_AUTOTASKS DBMS_SYS_ERROR NLS_SESSION_PARAMETERS
DBMS_ADVISOR_MESSAGE_GROUPS DBMS_UTILITY PRVT_ADVISOR
DBMS_ADVISOR DBMS_WORKLOAD_REPLAY_I PRVT_HDM
DBMS_LOB DUAL PRVT_SMGUTIL
DBMS_MANAGEMENT_PACKS JSON_ARRAY_T USER_ADVISOR_MESSAGE_GROUPS
DBMS_REPORT JSON_ELEMENT_T USER_ADVISOR_TASKS
DBMS_STANDARD JSON_OBJECT_T XMLTYPE
DBMS_SWRF_INTERNAL    
Documented Partial: Packages and Types Reference
First Available 11.1
Security Model Owned by SYS with EXECUTE granted to PUBLIC
Source {ORACLE_HOME}/rdbms/admin/dbmsaddm.sql
{ORACLE_HOME}/rdbms/admin/prvtaddm.plb
Subprograms
 
ANALYZE_DB
Create and execute an ADDM task to analyze all instances of a database for a range of snapshots dbms_addm.analyze_db(
task_name      IN OUT VARCHAR2,
begin_snapshot IN     NUMBER,
end_snapshot   IN     NUMBER,
db_id          IN     NUMBER := NULL);
SELECT dbid FROM v$database;

set pagesize 99
set linesize 141
col instart_fmt format a20
break on instart_fmt
col inst_name format a12 heading 'Instance';
col db_name format a12 heading 'DB Name';
col snap_id format 99999990 heading 'Snap Id';
col snapdat format a18 heading 'Snap Started' just c;
col lvl format 99 heading 'Snap|Level';
set heading on;
break on inst_name on db_name on host on instart_fmt skip 1;
ttitle off;

SELECT TO_CHAR(s.startup_time,' DD MON "at" HH24:MI:SS') INSTART_FMT,
di.instance_name INST_NAME, di.db_name DB_NAME, s.snap_id SNAP_ID,
TO_CHAR(s.end_interval_time,'DD MON YYYY HH24:MI') SNAPDAT,
s.snap_level LVL
FROM dba_hist_snapshot s, dba_hist_database_instance di
WHERE di.dbid = s.dbid
AND di.instance_number = s.instance_number
AND di.startup_time = s.startup_time
ORDER BY snap_id;

set serveroutput on

DECLARE
 tname VARCHAR2(30) := 'UW_TASK1';
BEGIN
  dbms_addm.analyze_db(tname, 2437, 2504, 1701481905);
  dbms_output.put_line(tname);
END;
/

col execution_name format a15
col finding_name format a30
col parent format 99
col impact format 99999999999
col message format a60
col more_info format a60

SELECT execution_name, finding_name, parent, impact
FROM dba_addm_findings
WHERE task_name = 'UW_TASK1';

SELECT execution_name, finding_name, message
FROM dba_addm_findings
WHERE task_name = 'UW_TASK1';

SELECT execution_name, finding_name, more_info
FROM dba_addm_findings
WHERE task_name = 'UW_TASK1';
 
ANALYZE_INST
Create and execute an ADDM task to analyze a specific instance of a database for a range of snapshots dbms_addm.analyze_inst(
task_name       IN OUT VARCHAR2,
begin_snapshot  IN     NUMBER,
end_snapshot    IN     NUMBER,
instance_number IN     NUMBER := NULL,
db_id           IN     NUMBER := NULL);
SELECT dbid FROM v$database;

SELECT inst_id
FROM gv$instance;

set pagesize 99
set linesize 141
col instart_fmt format a20
break on instart_fmt
col inst_name format a12 heading 'Instance';
col db_name format a12 heading 'DB Name';
col snap_id format 99999990 heading 'Snap Id';
col snapdat format a18 heading 'Snap Started' just c;
col lvl format 99 heading 'Snap|Level';
set heading on;
break on inst_name on db_name on host on instart_fmt skip 1;
ttitle off;

SELECT TO_CHAR(s.startup_time,' DD MON "at" HH24:MI:SS') INSTART_FMT,
di.instance_name INST_NAME, di.db_name DB_NAME, s.snap_id SNAP_ID,
TO_CHAR(s.end_interval_time,'DD MON YYYY HH24:MI') SNAPDAT,
s.snap_level LVL
FROM dba_hist_snapshot s, dba_hist_database_instance di
WHERE di.dbid = s.dbid
AND di.instance_number = s.instance_number
AND di.startup_time = s.startup_time
ORDER BY snap_id;

set serveroutput on

DECLARE
 tname VARCHAR2(30) := 'UW_TASK2';
BEGIN
  dbms_addm.analyze_inst(tname, 2387, 2406, 1, 1701481905);
  dbms_output.put_line(tname);
END;
/

desc dba_addm_findings

SELECT task_name
FROM dba_addm_findings;

SELECT task_name
FROM dba_addm_findings
WHERE task_name LIKE 'UW%';

col finding_name format a30
col impact format 99999.99

SELECT execution_name, finding_name, parent, impact, message, more_info
FROM dba_addm_findings
WHERE task_name = 'UW_TASK2';

desc dba_addm_tasks

SELECT DISTINCT task_name, advisor_name
FROM dba_addm_tasks;

col advisor_name format a15
col how_created format a15

SELECT advisor_name, status, how_created, system_task, requested_analysis, actual_analysis
FROM dba_addm_tasks
WHERE task_name = 'UW_TASK2';
 
ANALYZE_PARTIAL
Create and execute an ADDM task to analyze a partial list of instances for a range of snapshots dbms_addm.analyze_partial(
task_name        IN OUT VARCHAR2,
instance_numbers IN     VARCHAR2,
begin_snapshot   IN     NUMBER,
end_snapshot     IN     NUMBER,
db_id            IN     NUMBER := NULL);
SELECT dbid FROM v$database;

SELECT inst_id
FROM gv$instance;

set pagesize 99
set linesize 161
col instart_fmt format a20
break on instart_fmt
col inst_name format a12 heading 'Instance';
col db_name format a12 heading 'DB Name';
col snap_id format 99999990 heading 'Snap Id';
col snapdat format a18 heading 'Snap Started' just c;
col lvl format 99 heading 'Snap|Level';
set heading on;
break on inst_name on db_name on host on instart_fmt skip 1;
ttitle off;

SELECT TO_CHAR(s.startup_time,' DD MON "at" HH24:MI:SS') INSTART_FMT,
di.instance_name INST_NAME, di.db_name DB_NAME, s.snap_id SNAP_ID,
TO_CHAR(s.end_interval_time,'DD MON YYYY HH24:MI') SNAPDAT,
s.snap_level LVL
FROM dba_hist_snapshot s, dba_hist_database_instance di
WHERE di.dbid = s.dbid
AND di.instance_number = s.instance_number
AND di.startup_time = s.startup_time
ORDER BY snap_id;

set serveroutput on

DECLARE
 tname VARCHAR2(30) := 'UW_TASK3';
 insts VARCHAR2(50) := '1,2,3';
BEGIN
  dbms_addm.analyze_partial(tname, insts, 2387, 2406);
  dbms_output.put_line(tname);
END;
/
 
COMPARE_CAPTURE_REPLAY_REPORT
Create a report comparing the performance of a capture to a replay dbms_addm.compare_capture_replay_report(
replay_id   IN NUMBER,
report_type IN VARCHAR2 := 'HTML')
RETURN CLOB;
TBD
 
COMPARE_DATABASES
Create a report comparing the performance of a database over two different time periods or the performance of two different databases over two different time periods dbms_addm.compare_databases(
base_dbid          IN NUMBER   := NULL,
base_begin_snap_id IN NUMBER,
base_end_snap_id   IN NUMBER,
comp_dbid          IN NUMBER   := NULL,
comp_begin_snap_id IN NUMBER,
comp_end_snap_id   IN NUMBER,
report_type        IN VARCHAR2 := 'HTML')
RETURN CLOB;
SELECT dbid FROM v$database;

set feedback off
set heading on
set linesize 1500
set termout on
set trim on
set trimspool on
set veri off
col instart_fmt noprint;
col inst_name format a12 heading 'Instance';
col db_name format a12 heading 'DB Name';
col snap_id format 99999990 heading 'Snap Id';
col snapdat format a18 heading 'Snap Started' just c;
col lvl format 99 heading 'Snap|Level';
break on inst_name on db_name on host on instart_fmt skip 1;
ttitle off;

SELECT TO_CHAR(s.startup_time,' DD MON "at" HH24:MI:SS') INSTART_FMT,
di.instance_name INST_NAME, di.db_name DB_NAME, s.snap_id SNAP_ID,
TO_CHAR(s.end_interval_time,'DD MON YYYY HH24:MI') SNAPDAT,
s.snap_level LVL
FROM dba_hist_snapshot s, dba_hist_database_instance di
WHERE di.dbid = s.dbid
AND di.instance_number = s.instance_number
AND di.startup_time = s.startup_time
ORDER BY snap_id;

set pagesize 999
set linesize 161

spool /home/oracle/compare_db.html br>
SELECT dbms_addm.compare_databases(1984521206, 4502, 4532, 768045447, 4472, 4502, 'HTML')
FROM dual;

spool off


-- open the file in a browser and you will discover it is unreadable except in OEM
 
COMPARE_INSTANCES
Create a report comparing the performance of a single instance over two different time periods or the performance of two different instances over two different time periods dbms_addm.compare_instances(
base_dbid          IN NUMBER   := NULL,
base_instance_id   IN NUMBER,
base_begin_snap_id IN NUMBER,
base_end_snap_id   IN NUMBER,
comp_dbid          IN NUMBER   := NULL,
comp_instance_id   IN NUMBER,
comp_begin_snap_id IN NUMBER,
comp_end_snap_id   IN NUMBER,
report_type        IN VARCHAR2 := 'HTML')
RETURN CLOB;
SELECT dbid FROM v$database;

set feedback off
set heading on
set linesize 1500
set termout on
set trim on
set trimspool on
set veri off
col instart_fmt noprint;
col inst_name format a12 heading 'Instance';
col db_name format a12 heading 'DB Name';
col snap_id format 99999990 heading 'Snap Id';
col snapdat format a18 heading 'Snap Started' just c;
col lvl format 99 heading 'Snap|Level';
break on inst_name on db_name on host on instart_fmt skip 1;
ttitle off;

SELECT TO_CHAR(s.startup_time,' DD MON "at" HH24:MI:SS') INSTART_FMT,
di.instance_name INST_NAME, di.db_name DB_NAME, s.snap_id SNAP_ID,
TO_CHAR(s.end_interval_time,'DD MON YYYY HH24:MI') SNAPDAT,
s.snap_level LVL
FROM dba_hist_snapshot s, dba_hist_database_instance di
WHERE di.dbid = s.dbid
AND di.instance_number = s.instance_number
AND di.startup_time = s.startup_time
ORDER BY snap_id;

set 999
set linesize 161

spool /home/oracle/compare_db.html

SELECT dbms_addm.compare_instances(1984521206, 1, 4502, 4532, 1984521206, 2, 4472, 4502, 'HTML')
FROM dual;

spool off


-- open the file in a browser and you will discover it is unreadable except in OEM
 
COMPARE_REPLAY_REPLAY_REPORT
Create a report comparing the the performance of two replays dbms_addm.compare_replay_replay_report(
replay_id1  IN NUMBER,
replay_id2  IN NUMBER,
report_type IN VARCHAR2 := 'HTML')
RETURN CLOB
TBD
 
DELETE
Delete an ADDM task dbms_addm.delete(task_name IN VARCHAR2);
exec dbms_addm.delete('UW_TASK1');
 
DELETE_FINDING_DIRECTIVE
Delete an ADDM directive dbms_addm.delete_finding_directive(
task_name IN VARCHAR2,
dir_name  IN VARCHAR2);
SELECT task_name, directive_name, description
FROM dba_addm_task_directives;
 
DELETE_PARAMETER_DIRECTIVE
Delete an ADDM directive dbms_addm.delete_parameter_directive(
task_name IN VARCHAR2,
dir_name  IN VARCHAR2);
TBD
 
DELETE_SEGMENT_DIRECTIVE
Delete an ADDM directive dbms_addm.delete_segment_directive(
task_name IN VARCHAR2,
dir_name  IN VARCHAR2);
TBD
 
DELETE_SQL_DIRECTIVE
Delete an ADDM directive dbms_addm.delete_sql_directive(
task_name IN VARCHAR2,
dir_name  IN VARCHAR2);
TBD
 
FORMAT_MESSAGE  (new 23c)
Retrieves the text for an Oracle message file dbms_addm.format_message(
msg_id IN VARCHAR2,
a1 IN VARCHAR2 := NULL,
a2 IN VARCHAR2 := NULL,
a3 IN VARCHAR2 := NULL,
a4 IN VARCHAR2 := NULL,
a5 IN VARCHAR2 := NULL);
TBD
 
GET_ASH_QUERY
Retrieves the SQL text of an ASH query for a finding dbms_addm.get_ash_query(
task_name  IN VARCHAR2,
finding_id IN NUMBER)
RETURN VARCHAR2;
-- first run the ANALYZE_DB demo above over a range that has "real" work

SELECT finding_id, finding_name, message
FROM dba_advisor_findings
WHERE task_name = 'UW_TASK1';

SELECT dbms_addm.get_ash_query('UW_TASK1', 1) FROM dual;

col task_name format a25
col message format a50

SELECT task_name, finding_id, finding_name, message
FROM dba_advisor_findings;

SELECT dbms_addm.get_ash_query('ADDM:2495529197_1_25', 1) FROM dual;
SELECT dbms_addm.get_ash_query('ADDM:2495529197_1_3', 1) FROM dual;
 
GET_REPORT
Returns the ADDM report dbms_addm.get_report(task_name IN VARCHAR2) RETURN CLOB;
SELECT task_name
FROM dba_advisor_tasks;

set long 1000000
set serveroutput on

DECLARE
 rptlob CLOB;
BEGIN
  rptlob := dbms_addm.get_report('UW_TASK1');
  dbms_output.put_line(rptlob);
END;
/

SELECT * FROM TABLE(dbms_xplan.display_cursor('1tkztbrcvfcdw'));
 
INSERT_FINDING_DIRECTIVE
Insert a directive filtering a finding, either for a task or system wide dbms_addm.insert_finding_directive(
task_name           IN VARCHAR2,
dir_name            IN VARCHAR2,
finding_name        IN VARCHAR2,
min_active_sessions IN NUMBER := 0,
min_perc_impact     IN NUMBER := 0);
TBD
 
INSERT_PARAMETER_DIRECTIVE
Insert a directive filtering a recommendations to change a system parameter dbms_addm.insert_parameter_directive(
task_name      IN VARCHAR2,
dir_name       IN VARCHAR2,
parameter_name IN VARCHAR2);
TBD
 
INSERT_SEGMENT_DIRECTIVE
Insert a directive filtering recommendations to run the segment advisor

Overload 1
dbms_addm.insert_segment_directive(
task_name       IN VARCHAR2,
dir_name        IN VARCHAR2,
owner_name      IN VARCHAR2,
object_name     IN VARCHAR2 := NULL,
sub_object_name IN VARCHAR2 := NULL);
TBD
Overload 2 dbms_addm.insert_segment_directive(
task_name     IN VARCHAR2,
dir_name      IN VARCHAR2,
object_number IN NUMBER);
TBD
 
INSERT_SQL_DIRECTIVE
Insert a directive filtering SQL recommendations, either for a task or system wide dbms_addm.inset_sql_directive(
task_name           IN VARCHAR2,
dir_name            IN VARCHAR2,
sql_id              IN VARCHAR2,
min_active_sessions IN NUMBER := 0,
min_response_time   IN NUMBER := 0);
TBD
 
JSON_MESSAGE_TO_TEXT  (new 23c)
Coverts all text messages in an ADDM JSON report into text messages dbms_addm.json_message_text(json_message IN CLOB) RETURN VARCHAR2;
PRAGMA SUPPLEMENTAL_LOG_DATA(JSON_MESSAGE_TO_TEXT, READ_ONLY);
TBD
 
JSON_REPORT_TO_TEXT  (new 23c)
Converts an ADDM report in JSON format and converts it to a CLOB dbms_addm.json_report_to_text(
json_report           IN CLOB,
report_level          IN := 'TYPICAL',
use_original_language IN VARCHAR2 := 'N')
RETURN CLOB;
PRAGMA SUPPLEMENTAL_LOG_DATA(JSON_REPORT_TO_TEXT, READ_ONLY);
TBD
 
JSON_REPORT_TRANSLATE  (new 23c)
Takes an ADDM report in JSON format and converts it to a CLOB with text dbms_addm.json_report_translate(json_report IN CLOB) RETURN CLOB;
PRAGMA SUPPLEMENTAL_LOG_DATA(JSON_REPORT_TRANSLATE, READ_ONLY);
TBD
 
REAL_TIME_ADDM_REPORT
Returns a real-time ADDM report for the previous 5 minutes

Formatting at right produced manually to aid viewing the report's data
dbms_addm.real_time_addm_report RETURN CLOB;
set long 1000000
spool c:\temp\realtime_addm.html

SELECT dbms_addm.real_time_addm_report
FROM dual;

REAL_TIME_ADDM_REPORT
--------------------------------------------------------------------------------
<report db_version="23.0.0.0.0" cpu_cores="2" hyperthread="N" con_id="1"
  con_name="CDB$ROOT" timezone_offset="0" packs="0" service_type="0">
  <report_id><![CDATA[/orarep/rtaddm/main]]></report_id>
  <sql_data>
    <report_metadata instance_number="0" date_format="HH24:MI:SS MM/DD/YYYY"
     start_time="19:31:00 05/05/2023" report_time="19:36:03 05/05/2023"/>
    <system_config>
      <database dbid="1405253007" name="FREE" log_mode="NOARCHIVELOG" open_mode="READ
       WRITE" role="PRIMARY" force_log="NO" platform="Linux x86 64-bit" flashback_on="NO"
       unique_name="FREE" version="23.0.0.0.0"/>
      <instances>
        <instance number="1" name="FREE" host="localhost.localdomain"
         version="23.0.0.0.0" startup_time="11:09:36 05/05/2023" status="OPEN"
         logins="ALLOWED" shutdown_pending="NO"
         role="PRIMARY_INSTANCE" active="NORMAL"/>
      </instances>
    </system_config>
    <hangs><sessions/><blockers/><hang_info/></hangs>
    <metrics>
      <metric_names>
        <map name="User Transaction Per Sec" unit="Transactions Per Second" id="1"/>
        <map name="Logons Per Sec" unit="Logons Per Second" id="2"/>
        <map name="User Commits Per Sec" unit="Commits Per Second" id="3"/>
        <map name="User Rollbacks Per Sec" ="Rollbacks Per Second" id="4"/>
        <map name="Network Traffic Volume Per Sec" unit="Bytes Per Second" id="5"/>
        <map name="CPU Usage Per Sec" unit="CentiSeconds Per Second" id="6"/>
        <map name="Physical Read Total Bytes Per Sec" unit="Bytes Per Second" id="7"/>
        <map name="GC CR Block Received Per Second" unit="Blocks Per Second" id="8"/>
        <map name="GC Current Block Received Per Second" unit="Blocks Per Second" id="9"/>
        <map name="Global Cache Average CR Get Time" unit="CentiSeconds Per Get" id="10"/>
        <map name="Global Cache Average Current Get Time" unit="CentiSeconds Per Get" id="11"/>
        <map name="Global Cache Blocks Lost" unit="Blocks" id="12"/>
        <map name="Current Logons Count" unit="Logons" id="13"/>
        <map name="Current Open Cursors Count" unit="Cursors" id="14"/>
        <map name="Process Limit %" unit="% Processes/Limit" id="15"/>
        <map name="Session Limit %" unit="% Sessions/Limit" id="16"/>
        <map name="Executions Per Sec" unit="Executes Per Second" id="17"/>
        <map name="Database Time Per Sec" unit="CentiSeconds Per Second" id="18"/>
        <map name="Physical Write Total Bytes Per Sec" unit="Bytes Per Second" id="19"/>
        <map name="Host CPU Utilization (%)" unit="% Busy/(Idle+Busy)" id="20"/>
        <map name="Current OS Load" unit="Number Of Processes" id="21"/>
        <map name="Average Synchronous Single-Block Read Latency" unit="Milliseconds" id="22"/>
        <map name="Background CPU Usage Per Sec" unit="CentiSeconds Per Second" id="23"/>
        <map name="Total PGA Allocated" unit="bytes" id="24"/>
        <map name="Run Queue Per Sec" unit="Processes" id="25"/>
        <map name="VM in bytes Per Sec" unit="bytes per sec" id="26"/>
        <map name="VM out bytes Per Sec" unit="bytes per sec" id="27"/>
      </metric_names>
      <data>
        <m i="1" v=".02" ma=".034" mi=".016" id="1"/>
        <m i="1" v=".02" ma=".049" mi="0" id="2"/>
        <m i="1" v=".02" ma=".034" mi=".016" id="3"/>
        <m i="1" v="0" ma="0" mi="0" id="4"/>
        <m i="1" v="0" ma="0" mi="0" id="5"/>
        <m i="1" v=".079" ma=".121" mi=".053" id="6"/>
        <m i="1" v="6554.715" ma="6736.611" mi="6400" id="7"/>
        <m i="1" v="0" ma="0" mi="0" id="8"/>
        <m i="1" v="0" ma="0" mi="0" id="9"/>
        <m i="1" v="0" ma="0" mi="0" id="10"/>
        <m i="1" v="0" ma="0" mi="0" id="11"/>
        <m i="1" v="0" ma="0" mi="0" id="12"/>
        <m i="1" v="78.2" ma="79" mi="78" id="13"/>
        <m i="1" v="74.2" ma="75" mi="74" id="14"/>
        <m i="1" v="27.4" ma="27.667" mi="27.333" id="15"/>
        <m i="1" v="21.864" ma="22.034" mi="21.822" id="16"/>
        <m i="1" v="2.29" ma="3.076" mi="1.887" id="17"/>
        <m i="1" v=".127" ma=".214" mi=".077" id="18"/>
        <m i="1" v="16485.505" ma="20531.717" mi="15233.333" id="19"/>
        <m i="1" v="5.004" ma="5.811" mi="4.449" id="20"/>
        <m i="1" v=".42" ma=".649" mi=".26" id="21"/>
        <m i="1" v="0" ma="0" mi="0" id="22"/>
        <m i="1" v="1.81" ma="1.851" mi="1.772" id="23"/>
        <m i="1" v="239426764.8" ma="240799744" mi="239083520" id="24"/>
        <m i="1" v="0" ma="0" mi="0" id="25"/>
        <m i="1" v="0" ma="0" mi="0" id="26"/>
        <m i="1" v="0" ma="0" mi="0" id="27"/>
      </data>
    </metrics>
    <ash_data sampling_ratio="1" avg_active_sessions=".0013" secs="303"><op/>
      <sid/><evt/><service/><program/><module/><action/><sql/><data/>
    </ash_data>
    <osstat_pit>
      <stat i="1" name="NUM_CPUS" v="2"/>
      <stat i="1" name="NUM_CPU_CORES" v="2"/>
      <stat i="1" name="PHYSICAL_MEMORY_BYTES" v="4098252800"/>
    </osstat_pit>
    <memory>
      <mem i="1" n="pga" v="260059136"/><mem i="1" n="fixed_sga" v="10043728"/>
      <mem i="1" n="buffer_cache" v="889192448"/><mem i="1" n="log_buffer" v="2265088"/>
      <mem i="1" n="shared_io_pool" v="83886080"/><mem i="1" n="shared pool" v="479393712"/>
      <mem i="1" n="SP free" v="40699984"/>
      <mem i="1" n="large pool" v="16777216"/>
      <mem i="1" n="java pool" v="50331648"/>
      <mem i="1" n="streams pool" v="16777216"/>
    </memory>
  <resize_ops/>
    <parameters>
      <p n="active_instance_count" i="1"/>
      <p n="event" i="1"/><p n="max_dispatchers" i="1"/>
      <p n="timed_os_statistics" i="0">0</p>
      <p n="shared_pool_size" i="0">0</p>
      <p n="db_2k_cache_size" i="0">0</p>
      <p n="db_8k_cache_size" i="0">0</p>
      <p n="db_32k_cache_size" i="0">0</p>
      <p n="db_keep_cache_size" i="0">0</p>
      <p n="timed_statistics" i="0">TRUE</p>
      <p n="large_pool_size" i="0">0</p>
      <p n="db_file_multiblock_read_count" i="0">128</p>
      <p n="statistics_level" i="0">TYPICAL</p>
      <p n="sessions" i="0">472</p>
      <p n="db_block_buffers" i="0">0</p>
      <p n="db_block_size" i="0">8192</p>
      <p n="compatible" i="0">23.0.0</p>
      <p n="_column_level_stats" i="0">OFF</p>
      <p n="sga_max_size" i="0">1610612736</p>
      <p n="gcs_server_processes" i="0">0</p>
      <p n="db_cache_size" i="0">0</p>
      <p n="db_block_checking" i="0">FALSE</p>
      <p n="cursor_sharing" i="0">EXACT</p>
      <p n="processes" i="0">300</p>
      <p n="memory_target" i="0">0</p>
      <p n="memory_max_target" i="0">0</p>
      <p n="log_buffer" i="0">4292608</p>
      <p n="_ash_size" i="0">25165824</p>
      <p n="cpu_count" i="0">2</p>
      <p n="java_pool_size" i="0">0</p>
      <p n="db_recycle_cache_size" i="0">0</p>
      <p n="open_cursors" i="0">300</p>
      <p n="pga_aggregate_target" i="0">536870912</p>
      <p n="sga_target" i="0">1610612736</p>
      <p n="db_block_checksum" i="0">TYPICAL</p>
      <p n="db_4k_cache_size" i="0">0</p>
      <p n="undo_management" i="0">AUTO</p>
      <p n="dispatchers" i="0">(PROTOCOL=TCP) (SERVICE=FREEXDB)</p>
      <p n="streams_pool_size" i="0">0</p>
      <p n="db_16k_cache_size" i="0">0</p>
      <p n="db_writer_processes" i="0">1</p>
      <p n="cluster_database" i="0">FALSE</p>
    </parameters>
  </sql_data>
</report>

SQL> spool off

-- open the report in a text editor
 
REEXECUTE_FAILED_AUTO_TASKS
Re-executes the tasks registered in DBA_ADDM_PENDING_AUTOTASKS dbms_addm.reexecute_failed_auto_tasks(
instance_number    IN NUMBER :=NULL,
begin_snapshot     IN NUMBER :=NULL,
end_snapshot       IN NUMBER :=NULL,
dbid               IN NUMBER :=NULL,
time_budget_in_sec IN NUMBER :=NULL,
max_attempts       IN NUMBER :=NULL);
TBD

Related Topics
Built-in Functions
Built-in Packages
DBMS_ADVISOR
DBMS_SQLTUNE
DBMS_WORKLOAD_REPLAY
DBMS_XPLAN
PRVT_HDM
What's New In 21c
What's New In 23c

Morgan's Library Page Footer
This site is maintained by Dan Morgan. Last Updated: This site is protected by copyright and trademark laws under U.S. and International law. © 1998-2023 Daniel A. Morgan All Rights Reserved
  DBSecWorx