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.
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;
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';
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;
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;
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;
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;
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);
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);
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);
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);
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);