From bd61da9eb907ce58dfb522076d58255d01aca70e Mon Sep 17 00:00:00 2001
From: Prashant Dixit <34828819+fatdba@users.noreply.github.com>
Date: Thu, 10 Feb 2022 14:19:26 +0530
Subject: [PATCH] Create PXHCDR.sql
It performs two functions:
a set of pre-defined health-checks around parallel execution setup system-wide.
generates some html reports to diagnose PX issues. These diagnostics reports are based mainly on PX dynamic and static views.
This script installs nothing on the database, and updates nothing. Thus it is safe to use it on a production environment. It also works on read-only systems.
Script pxhcdr.sql only asks for two parameters: enter "D" if you have the Oracle Diagnostics Pack only. Enter "T" if you have the Oracle Tuning Pack license (which requires having the Diagnostic Pack license). Enter "N" if you have neither license. The second parameter is directory.
---
PXHCDR.sql | 2429 ++++++++++++++++++++++++++++++++++++++++++++++++++++
1 file changed, 2429 insertions(+)
create mode 100644 PXHCDR.sql
diff --git a/PXHCDR.sql b/PXHCDR.sql
new file mode 100644
index 0000000..9254055
--- /dev/null
+++ b/PXHCDR.sql
@@ -0,0 +1,2429 @@
+-- Oracle provided script
+SPO pxhcdr.log
+SET DEF ^ TERM OFF ECHO ON VER OFF SERVEROUT ON SIZE 1000000;
+REM
+REM $Header: 1460440.1 pxhcdr.sql 12.1.09 2013/06/13 carlos.sierra mauro.pagano $
+REM
+REM Copyright (c) 2000-2013, Oracle Corporation. All rights reserved.
+REM
+REM AUTHOR
+REM carlos.sierra@oracle.com
+REM mauro.pagano@oracle.com
+REM
+REM SCRIPT
+REM pxhcdr.sql
+REM
+REM DESCRIPTION
+REM Parallel Execution Health-Checks and Diagnostics Reports.
+REM
+REM This read-only script performs two functions with regard to
+REM system-wide parallel execution:
+REM 1. Reports on a set of commonly used health-checks.
+REM 2. Generates a set of diagnostics reports based on PX
+REM performance views, PX static views and system tables.
+REM
+REM Since pxhcdr.sql is a read-only script, which installs nothing
+REM and updates nothing, it is safe to use on any Oracle database
+REM 10g or higher, including Dataguard and read-only systems.
+REM
+REM PRE-REQUISITES
+REM 1. Execute as SYS or user with DBA role or user with access
+REM to data dictionary views.
+REM
+REM PARAMETERS
+REM 1. Oracle Pack license (Tuning or Diagnostics or None) T|D|N
+REM 2. Target directory path for output (optional). Default is cuurent.
+REM
+REM EXECUTION
+REM 1. Start SQL*Plus connecting as SYS or user with DBA role or
+REM user with access to data dictionary views.
+REM 2. Execute script pxhcdr.sql passing values for parameter.
+REM
+REM EXAMPLE
+REM # sqlplus / as sysdba
+REM SQL> START [path]pxhcdr.sql [T|D|N] [target_path]
+REM
+REM NOTES
+REM 1. For possible errors see pxhcdr.log.
+REM 2. If site has both Tuning and Diagnostics licenses then
+REM specified T (Oracle Tuning pack includes Oracle Diagnostics)
+REM
+DEF monitor_reports = '25';
+DEF small_table_threshold = '1e9';
+
+/**************************************************************************************************/
+
+SET TERM ON ECHO OFF;
+PRO
+PRO Parameter 1:
+PRO Oracle Pack License (Tuning, Diagnostics or None) [T|D|N] (required)
+PRO
+DEF input_license = '^1';
+PRO
+PRO Parameter 2:
+PRO Target directory path for script output (optional)
+PRO
+DEF output_path = '^2';
+PRO
+SET TERM OFF;
+COL license NEW_V license FOR A1;
+
+SELECT UPPER(SUBSTR(TRIM('^^input_license.'), 1, 1)) license FROM DUAL;
+
+VAR license CHAR(1);
+EXEC :license := '^^license.';
+
+COL full_path NEW_V full_path;
+SELECT TRIM('^^output_path.')||CASE
+WHEN INSTR('^^output_path.', '/') > 0 THEN '/'
+WHEN INSTR('^^output_path.', '\') > 0 THEN '\'
+END full_path
+FROM DUAL;
+
+COL unique_id NEW_V unique_id FOR A15;
+SELECT TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS') unique_id FROM DUAL;
+
+SET TERM ON;
+WHENEVER SQLERROR EXIT SQL.SQLCODE;
+
+BEGIN
+ IF '^^license.' IS NULL OR '^^license.' NOT IN ('T', 'D', 'N') THEN
+ RAISE_APPLICATION_ERROR(-20100, 'Oracle Pack License (Tuning, Diagnostics or None) must be specified as "T" or "D" or "N".');
+ END IF;
+END;
+/
+
+WHENEVER SQLERROR CONTINUE;
+
+PRO Value passed:
+PRO ~~~~~~~~~~~~
+PRO License: "^^input_license."
+PRO
+
+SET ECHO ON TIMI ON;
+
+DEF script = 'pxhcdr';
+DEF method = 'PXHCDR';
+
+DEF mos_doc = '1460440.1';
+DEF doc_ver = '12.1.09';
+DEF doc_date = '2014/06/13';
+DEF doc_link = 'https://support.oracle.com/CSP/main/article?cmd=show&type=NOT&id=';
+DEF bug_link = 'https://support.oracle.com/CSP/main/article?cmd=show&type=BUG&id=';
+
+-- tracing script in case it takes long to execute so we can diagnose it
+ALTER SESSION SET TRACEFILE_IDENTIFIER = "^^script._^^unique_id.";
+ALTER SESSION SET STATISTICS_LEVEL = 'ALL';
+ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 12';
+
+/**************************************************************************************************/
+
+/* -------------------------
+ *
+ * assembly title
+ *
+ * ------------------------- */
+
+-- get database name (up to 10, stop before first '.', no special characters)
+COL database_name_short NEW_V database_name_short FOR A10;
+SELECT SUBSTR(SYS_CONTEXT('USERENV', 'DB_NAME'), 1, 10) database_name_short FROM DUAL;
+SELECT SUBSTR('^^database_name_short.', 1, INSTR('^^database_name_short..', '.') - 1) database_name_short FROM DUAL;
+SELECT TRANSLATE('^^database_name_short.',
+'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789 ''`~!@#$%^*()-_=+[]{}\|;:",.<>/?'||CHR(0)||CHR(9)||CHR(10)||CHR(13)||CHR(38),
+'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789') database_name_short FROM DUAL;
+
+-- get host name (up to 30, stop before first '.', no special characters)
+COL host_name_short NEW_V host_name_short FOR A30;
+SELECT SUBSTR(SYS_CONTEXT('USERENV', 'SERVER_HOST'), 1, 30) host_name_short FROM DUAL;
+SELECT SUBSTR('^^host_name_short.', 1, INSTR('^^host_name_short..', '.') - 1) host_name_short FROM DUAL;
+SELECT TRANSLATE('^^host_name_short.',
+'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789 ''`~!@#$%^*()-_=+[]{}\|;:",.<>/?'||CHR(0)||CHR(9)||CHR(10)||CHR(13)||CHR(38),
+'ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789') host_name_short FROM DUAL;
+
+-- get rdbms version
+COL rdbms_version NEW_V rdbms_version FOR A17;
+SELECT version rdbms_version FROM v$instance;
+
+-- get platform
+COL platform NEW_V platform FOR A80;
+SELECT UPPER(TRIM(REPLACE(REPLACE(product, 'TNS for '), ':' ))) platform FROM product_component_version WHERE product LIKE 'TNS for%' AND ROWNUM = 1;
+
+-- get instance
+COL instance_number NEW_V instance_number FOR A10;
+SELECT TO_CHAR(instance_number) instance_number FROM v$instance;
+
+-- YYYYMMDD_HH24MISS
+COL time_stamp NEW_V time_stamp FOR A15;
+SELECT TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS') time_stamp FROM DUAL;
+
+-- YYYY-MM-DD/HH24:MI:SS
+COL time_stamp2 NEW_V time_stamp2 FOR A20;
+SELECT TO_CHAR(SYSDATE, 'YYYY-MM-DD/HH24:MI:SS') time_stamp2 FROM DUAL;
+
+-- get db_block_size
+COL sys_db_block_size NEW_V sys_db_block_size FOR A17;
+SELECT value sys_db_block_size FROM v$system_parameter2 WHERE LOWER(name) = 'db_block_size';
+
+-- get cpu_count
+COL sys_cpu NEW_V sys_cpu FOR A17;
+SELECT value sys_cpu FROM v$system_parameter2 WHERE LOWER(name) = 'cpu_count';
+
+-- get ofe
+COL sys_ofe NEW_V sys_ofe FOR A17;
+SELECT value sys_ofe FROM v$system_parameter2 WHERE LOWER(name) = 'optimizer_features_enable';
+
+-- get ds
+COL sys_ds NEW_V sys_ds FOR A10;
+SELECT value sys_ds FROM v$system_parameter2 WHERE LOWER(name) = 'optimizer_dynamic_sampling';
+
+/* -------------------------
+ *
+ * application vendor
+ *
+ * ------------------------- */
+
+-- ebs
+COL is_ebs NEW_V is_ebs FOR A1;
+COL ebs_owner NEW_V ebs_owner FOR A30;
+SELECT 'Y' is_ebs, owner ebs_owner
+ FROM dba_tab_columns
+ WHERE table_name = 'FND_PRODUCT_GROUPS'
+ AND column_name = 'RELEASE_NAME'
+ AND data_type = 'VARCHAR2'
+ AND ROWNUM = 1;
+
+-- siebel
+COL is_siebel NEW_V is_siebel FOR A1;
+COL siebel_owner NEW_V siebel_owner FOR A30;
+SELECT 'Y' is_siebel, owner siebel_owner
+ FROM dba_tab_columns
+ WHERE '^^is_ebs.' IS NULL
+ AND table_name = 'S_REPOSITORY'
+ AND column_name = 'ROW_ID'
+ AND data_type = 'VARCHAR2'
+ AND ROWNUM = 1;
+
+-- psft
+COL is_psft NEW_V is_psft FOR A1;
+COL psft_owner NEW_V psft_owner FOR A30;
+SELECT 'Y' is_psft, owner psft_owner
+ FROM dba_tab_columns
+ WHERE '^^is_ebs.' IS NULL
+ AND '^^is_siebel.' IS NULL
+ AND table_name = 'PSSTATUS'
+ AND column_name = 'TOOLSREL'
+ AND data_type = 'VARCHAR2'
+ AND ROWNUM = 1;
+
+/**************************************************************************************************/
+
+/* -------------------------
+ *
+ * main report
+ *
+ * ------------------------- */
+
+-- setup to produce report
+SET ECHO OFF FEED OFF VER OFF SHOW OFF HEA OFF LIN 2000 NEWP NONE PAGES 0 NUM 20 LONG 2000000 LONGC 2000 SQLC MIX TAB ON TRIMS ON TI OFF TIMI OFF ARRAY 100 NUMF "" SQLP SQL> SUF sql BLO . RECSEP OFF APPI OFF AUTOT OFF;
+
+/* -------------------------
+ *
+ * gv$sql_shared_cursor
+ *
+ * ------------------------- */
+SPO sql_shared_cursor.sql;
+PRO SELECT /* ^^script..sql Cursor Sharing as per Reason */
+PRO CHR(10)||'
'||CHR(10)||
+PRO ''||ROWNUM||' | '||CHR(10)||
+PRO ''||v2.reason||' | '||CHR(10)||
+PRO ''||v2.inst_id||' | '||CHR(10)||
+PRO ''||v2.cursors||' | '||CHR(10)||
+PRO '
'
+PRO FROM (
+SELECT (CASE WHEN ROWNUM > 1 THEN 'UNION ALL'||CHR(10) END)||
+ 'SELECT '''||v.column_name||''' reason, inst_id, COUNT(*) cursors FROM gv$sql_shared_cursor WHERE '||v.column_name||' = ''Y'' GROUP BY inst_id' line
+ FROM (
+SELECT /*+ NO_MERGE */
+ column_name
+ FROM dba_tab_cols
+ WHERE owner = 'SYS'
+ AND table_name = 'GV_$SQL_SHARED_CURSOR'
+ AND data_type = 'VARCHAR2'
+ AND data_length = 1
+ ORDER BY
+ column_name ) v;
+PRO ORDER BY reason, inst_id ) v2;;
+SPO OFF;
+
+/* -------------------------
+ *
+ * heading
+ *
+ * ------------------------- */
+SPO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._main.html;
+
+PRO
+PRO
+PRO
+PRO
+PRO
+PRO
+PRO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._main.html
+PRO
+
+PRO
+PRO
+
+PRO
+PRO
+PRO ^^mos_doc. ^^method.
+PRO ^^doc_ver. Report: ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._main.html
+PRO
+
+PRO
+PRO License : ^^input_license.
+PRO RDBMS : ^^rdbms_version.
+PRO Platform : ^^platform.
+PRO Instance : ^^instance_number.
+PRO CPU Count : ^^sys_cpu.
+PRO Block Size: ^^sys_db_block_size.
+PRO OFE : ^^sys_ofe.
+PRO DYN_SAMP : ^^sys_ds.
+PRO EBS : "^^is_ebs."
+PRO SIEBEL : "^^is_siebel."
+PRO PSFT : "^^is_psft."
+PRO Date : ^^time_stamp2.
+PRO
+
+PRO
+
+/* -------------------------
+ *
+ * observations
+ *
+ * ------------------------- */
+PRO Observations
+PRO
+PRO Observations below are the outcome of several heath-checks on your system with regard to Parallel Execution (PX).
+PRO Review them carefully and take action when appropriate.
+PRO Note: Ignore possible errors about dba_rsrc_io_calibrate and gv$io_calibration_status on 10g:
+PRO
+PRO
+PRO
+PRO
+PRO Type |
+PRO Name |
+PRO Observation |
+PRO Details |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+-- parallel_instance_group not in services or instance_groups
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_instance_group | '||CHR(10)||
+ 'Value "'||pig.value||'" on instance '||pig.inst_id||' does not exist as a service or instance group. | '||CHR(10)||
+ 'Unset this parallel_instance_group or verify it matches a valid service or a value in instance_groups parameter. '||CHR(10)||
+ 'See 7352775.8, 750645.1 and 13940162. | '||CHR(10)||
+ '
'
+ FROM gv$system_parameter2 pig
+ WHERE LOWER(pig.name) = 'parallel_instance_group'
+ AND TRIM(REPLACE(REPLACE(pig.value, ''''), '"')) IS NOT NULL
+ AND NOT EXISTS (
+SELECT NULL
+ FROM gv$services gsv
+ WHERE gsv.name = pig.value )
+ AND NOT EXISTS (
+SELECT NULL
+ FROM gv$system_parameter2 igr
+ WHERE LOWER(igr.name) = 'instance_groups'
+ AND igr.value = pig.value );
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_instance_group is set or modified to a null value
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_instance_group | '||CHR(10)||
+ 'A NULL value of this parameter on instance '||pig.inst_id||' is not valid. | '||CHR(10)||
+ 'Unset this parallel_instance_group parameter altogether. | '||CHR(10)||
+ '
'
+ FROM gv$system_parameter2 pig
+ WHERE LOWER(pig.name) = 'parallel_instance_group'
+ AND TRIM(REPLACE(REPLACE(pig.value, ''''), '"')) IS NULL
+ AND (pig.isdefault = 'FALSE' OR pig.ismodified <> 'FALSE');
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_max_servers > cpu_count * 4 * parallel_threads_per_cpu
+WITH
+pms AS (SELECT /*+ MATERIALIZE */ inst_id, TO_NUMBER(value) value FROM gv$system_parameter2 WHERE LOWER(name) = 'parallel_max_servers'),
+cpc AS (SELECT /*+ MATERIALIZE */ inst_id, TO_NUMBER(value) value FROM gv$system_parameter2 WHERE LOWER(name) = 'cpu_count'),
+tpc AS (SELECT /*+ MATERIALIZE */ inst_id, TO_NUMBER(value) value FROM gv$system_parameter2 WHERE LOWER(name) = 'parallel_threads_per_cpu'),
+wsp AS (SELECT /*+ MATERIALIZE */ inst_id, CASE WHEN value = 'AUTO' THEN 2 ELSE 1 END value FROM gv$system_parameter2 WHERE LOWER(name) = 'workarea_size_policy'),
+stg AS (SELECT /*+ MATERIALIZE */ inst_id, CASE WHEN value > 0 THEN 4 ELSE NULL END value FROM gv$system_parameter2 WHERE LOWER(name) = 'sga_target'),
+mtg AS (SELECT /*+ MATERIALIZE */ inst_id, CASE WHEN value > 0 THEN 4 ELSE NULL END value FROM gv$system_parameter2 WHERE LOWER(name) = 'memory_target'),
+vrs AS (SELECT /*+ MATERIALIZE */ substr(version,1,4) version from gv$instance)
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_max_servers | '||CHR(10)||
+ 'A value of '||pms.value||' for this parameter on instance '||pms.inst_id||' seems too high. | '||CHR(10)||
+ 'Consider reducing this value to at most cpu_count * parallel_threads_per_cpu '||CASE WHEN vrs.version >= '11.2' THEN '* 5 * concurrent_parallel_users' ELSE '* 4' END ||'. '||CHR(10)||
+ 'Current value for cpu_count is '||cpc.value||' and for parallel_threads_per_cpu is '||tpc.value||'. | '||CHR(10)||
+ '
'
+ FROM pms, cpc, tpc, wsp, stg, mtg, vrs
+ WHERE pms.inst_id = cpc.inst_id
+ AND cpc.inst_id = tpc.inst_id
+ AND tpc.inst_id = pms.inst_id
+ AND cpc.inst_id = wsp.inst_id
+ AND cpc.inst_id = stg.inst_id(+)
+ AND cpc.inst_id = mtg.inst_id(+)
+ AND pms.value > CASE WHEN vrs.version >= '11.2' THEN cpc.value * 5 * tpc.value * NVL(mtg.value,NVL(stg.value,wsp.value)) ELSE cpc.value * 4 * tpc.value END;
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_servers_target > 0.75 * parallel_max_servers
+WITH
+pst AS (SELECT /*+ MATERIALIZE */ inst_id, TO_NUMBER(value) value FROM gv$system_parameter2 WHERE LOWER(name) = 'parallel_servers_target'),
+pms AS (SELECT /*+ MATERIALIZE */ inst_id, TO_NUMBER(value) value FROM gv$system_parameter2 WHERE LOWER(name) = 'parallel_max_servers')
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_servers_target | '||CHR(10)||
+ 'A value of '||pst.value||' for this parameter on instance '||pst.inst_id||' seems too high. | '||CHR(10)||
+ 'Consider reducing this value to at most 0.75 * parallel_max_servers. '||CHR(10)||
+ 'Current value for parallel_max_servers is '||pms.value||'. | '||CHR(10)||
+ '
'
+ FROM pst, pms
+ WHERE pst.inst_id = pms.inst_id
+ AND pst.value > 0.75 * pms.value;
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_adaptive_multi_user is set
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_adaptive_multi_user | '||CHR(10)||
+ 'Parallel adaptive muti-user is enabled on instance '||amu.inst_id||'. | '||CHR(10)||
+ 'Be aware that degree of parallelism (DOP) may be reduced at time of execution. | '||CHR(10)||
+ '
'
+ FROM gv$system_parameter2 amu
+ WHERE LOWER(amu.name) = 'parallel_adaptive_multi_user'
+ AND amu.value = 'TRUE';
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_automatic_tuning is set
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_automatic_tuning | '||CHR(10)||
+ 'Parallel automatic tuning is enabled on instance '||aut.inst_id||'. | '||CHR(10)||
+ 'This parameter is deprecated as of 10g. Avoid using it. | '||CHR(10)||
+ '
'
+ FROM gv$system_parameter2 aut
+ WHERE LOWER(aut.name) = 'parallel_automatic_tuning'
+ AND aut.value = 'TRUE';
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_execution_message_size has different values
+WITH
+ems AS (SELECT /*+ MATERIALIZE */ MIN(TO_NUMBER(value)) min_value, MAX(TO_NUMBER(value)) max_value FROM gv$system_parameter2 WHERE LOWER(name) = 'parallel_execution_message_size')
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_execution_message_size | '||CHR(10)||
+ 'Parallel execution message size ranges between '||ems.min_value||' and '||ems.max_value||'. | '||CHR(10)||
+ 'All RAC nodes must have same value. Fix this error immediately. '||CHR(10)||
+ 'See 752967.1, 1374088.1 and 7486699. | '||CHR(10)||
+ '
'
+ FROM ems
+ WHERE ems.min_value <> ems.max_value;
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_execution_message_size < 8K
+WITH
+ems AS (SELECT /*+ MATERIALIZE */ inst_id, TO_NUMBER(value) value FROM gv$system_parameter2 WHERE LOWER(name) = 'parallel_execution_message_size')
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_execution_message_size | '||CHR(10)||
+ 'Parallel execution message size of '||ems.value||' in instance '||ems.inst_id||' is too small. | '||CHR(10)||
+ 'A size smaller than 8K may produce message fragmentation "PX Deq: Msg Fragment". Consider increasing the message size. '||CHR(10)||
+ 'See 254760.1 and 9792010.8. | '||CHR(10)||
+ '
'
+ FROM ems
+ WHERE ems.value < 8192;
+
+SELECT '' FROM dual;
+PRO
+
+-- 11g dba_rsrc_io_calibrate
+SELECT CHR(10)||''||CHR(10)||
+ 'IO Calibration Results | '||CHR(10)||
+ 'dba_rsrc_io_calibrate | '||CHR(10)||
+ 'There seems to be no I/O Calibration results. | '||CHR(10)||
+ 'Consider using DBMS_RESOURCE_MANAGER.CALIBRATE_IO. | '||CHR(10)||
+ '
'
+ FROM dba_rsrc_io_calibrate
+ WHERE '^^rdbms_version.' LIKE '11%'
+HAVING COUNT(*) = 0;
+
+SELECT '' FROM dual;
+PRO
+
+-- 11g gv$io_calibration_status
+SELECT CHR(10)||''||CHR(10)||
+ 'IO Calibration Status | '||CHR(10)||
+ 'gv$io_calibration_status | '||CHR(10)||
+ ''||status||' for instance '||inst_id||'. | '||CHR(10)||
+ 'Time of last calibration: '||calibration_time||'. | '||CHR(10)||
+ '
'
+ FROM gv$io_calibration_status
+ ORDER BY
+ inst_id;
+
+SELECT '' FROM dual;
+PRO
+
+-- parallel_degree_policy is set to AUTO
+SELECT CHR(10)||''||CHR(10)||
+ 'System Parameter | '||CHR(10)||
+ 'parallel_degree_policy | '||CHR(10)||
+ 'Parallel degree policy is set to AUTO in '||COUNT(*)||' instance(s). | '||CHR(10)||
+ 'AUTO enables automatic degree of parallelism, statement queuing, and in-memory parallel execution. | '||CHR(10)||
+ '
'
+ FROM gv$system_parameter2 pdp
+ WHERE LOWER(pdp.name) = 'parallel_degree_policy'
+ AND pdp.value = 'AUTO'
+HAVING COUNT(*) > 0;
+
+SELECT '' FROM dual;
+PRO
+
+-- tables < 1G with dop <> 1
+WITH
+tables AS (
+SELECT /*+ MATERIALIZE */
+ t.owner,
+ t.table_name,
+ TRIM(t.degree)table_degree,
+ t.blocks,
+ t.partitioned tab_part,
+ t.temporary
+ FROM dba_tables t
+ WHERE t.degree IS NOT NULL
+ AND TRIM(t.degree) <> '1'
+ AND t.blocks * ^^sys_db_block_size. < ^^small_table_threshold.
+)
+SELECT CHR(10)||''||CHR(10)||
+ 'Degree of Parallelism | '||CHR(10)||
+ 'Non-default DOP | '||CHR(10)||
+ 'Schema '||owner||' contains '||COUNT(*)||' small table(s) with DOP set. | '||CHR(10)||
+ 'Setting DOP in small tables (smaller than '||ROUND(^^small_table_threshold./1e9, 3)||' GB) may promote PX plans for which a serial plan may be more convenient. Review DOP report. | '||CHR(10)||
+ '
'
+ FROM tables
+ GROUP BY
+ owner
+ ORDER BY
+ owner;
+
+SELECT '' FROM dual;
+PRO
+
+-- tables dop <> indexes dop
+WITH
+tables_n_indexes AS (
+SELECT /*+ MATERIALIZE */
+ t.owner,
+ t.table_name,
+ TRIM(t.degree) table_degree,
+ TRIM(t.instances) table_instances,
+ t.blocks,
+ t.partitioned tab_part,
+ t.temporary,
+ i.index_name,
+ i.index_type,
+ TRIM(i.degree) index_degree,
+ TRIM(i.instances) index_instances,
+ i.leaf_blocks,
+ i.partitioned idx_part
+ FROM dba_tables t,
+ dba_indexes i
+ WHERE t.degree IS NOT NULL
+ AND i.table_owner = t.owner
+ AND i.table_name = t.table_name
+ AND i.table_type = 'TABLE'
+ AND i.index_type <> 'LOB'
+ AND i.degree IS NOT NULL
+ AND TRIM(i.degree) <> TRIM(t.degree)
+),
+tables AS (
+SELECT /*+ MATERIALIZE */
+ owner,
+ table_name
+ FROM tables_n_indexes
+ GROUP BY
+ owner,
+ table_name
+)
+SELECT CHR(10)||''||CHR(10)||
+ 'Degree of Parallelism | '||CHR(10)||
+ 'DOP mismatch | '||CHR(10)||
+ 'Schema '||owner||' contains '||COUNT(*)||' table(s) with DOP different than one or more index(es). | '||CHR(10)||
+ 'This DOP mismatch between tables and indexes is more probably by accident. It may produce some unexpected PX plans. Review DOP report. | '||CHR(10)||
+ '
'
+ FROM tables
+ GROUP BY
+ owner
+ ORDER BY
+ owner;
+
+PRO
+PRO
+PRO Type |
+PRO Name |
+PRO Observation |
+PRO Details |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * parallel degree limit method
+ *
+ * ------------------------- */
+PRO Parallel Degree Limit Method
+PRO
+PRO Collected from GV$PARALLEL_DEGREE_LIMIT_MTH.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Name |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.name||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ name
+ FROM gv$parallel_degree_limit_mth
+ ORDER BY
+ inst_id,
+ name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Name |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * px buffer advice
+ *
+ * ------------------------- */
+PRO PX Buffer Advice
+PRO
+PRO Collected from GV$PX_BUFFER_ADVICE.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.statistic||' | '||CHR(10)||
+ ''||value||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ statistic,
+ value
+ FROM gv$px_buffer_advice
+ ORDER BY
+ inst_id,
+ statistic ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * pq system statistics
+ *
+ * ------------------------- */
+PRO PQ System Statistics
+PRO
+PRO Collected from GV$PQ_SYSSTAT.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.statistic||' | '||CHR(10)||
+ ''||v.value||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ statistic,
+ value
+ FROM gv$pq_sysstat
+ ORDER BY
+ inst_id,
+ statistic ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * px system statistics
+ *
+ * ------------------------- */
+PRO PX System Statistics
+PRO
+PRO Collected from GV$PX_PROCESS_SYSSTAT.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.statistic||' | '||CHR(10)||
+ ''||v.value||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ statistic,
+ value
+ FROM gv$px_process_sysstat
+ ORDER BY
+ inst_id,
+ statistic ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * system statistics
+ *
+ * ------------------------- */
+PRO System Statistics
+PRO
+PRO Collected from GV$SYSSTAT.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.name||' | '||CHR(10)||
+ ''||v.value||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ name,
+ value
+ FROM gv$sysstat
+ ORDER BY
+ inst_id,
+ name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Statistic |
+PRO Value |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * pq slaves
+ *
+ * ------------------------- */
+PRO PQ Slaves
+PRO
+PRO Collected from GV$PQ_SLAVE.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Slave Name |
+PRO Status |
+PRO Sessions |
+PRO Idle Time Total |
+PRO Busy Time Total |
+PRO CPU Secs Total |
+PRO Msgs Sent Total |
+PRO Msgs Rcvd Total |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.slave_name||' | '||CHR(10)||
+ ''||v.status||' | '||CHR(10)||
+ ''||v.sessions||' | '||CHR(10)||
+ ''||v.idle_time_total||' | '||CHR(10)||
+ ''||v.busy_time_total||' | '||CHR(10)||
+ ''||v.cpu_secs_total||' | '||CHR(10)||
+ ''||v.msgs_sent_total||' | '||CHR(10)||
+ ''||v.msgs_rcvd_total||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ slave_name,
+ status,
+ sessions,
+ idle_time_total,
+ busy_time_total,
+ cpu_secs_total,
+ msgs_sent_total,
+ msgs_rcvd_total
+ FROM gv$pq_slave
+ ORDER BY
+ inst_id,
+ slave_name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Slave Name |
+PRO Status |
+PRO Sessions |
+PRO Idle Time Total |
+PRO Busy Time Total |
+PRO CPU Secs Total |
+PRO Msgs Sent Total |
+PRO Msgs Rcvd Total |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * px sessions
+ *
+ * ------------------------- */
+PRO PX Sessions
+PRO
+PRO Collected from GV$PX_SESSION.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO QC SID |
+PRO Server Name |
+PRO SID |
+PRO Serial# |
+PRO PID |
+PRO SPID |
+PRO Server Group |
+PRO Server Set |
+PRO Server# |
+PRO Degree |
+PRO Req Degree |
+PRO Wait Event |
+PRO SQL_ID |
+PRO Child# |
+PRO Resource Consumer Group |
+PRO Module |
+PRO Action |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT /* ^^script..sql PX Sessions */
+ CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ v.line||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ ''||pxs.inst_id||' | '||CHR(10)||
+ ''||pxs.qcsid||' | '||CHR(10)||
+ ''||NVL(pxp.server_name, 'QC')||' | '||CHR(10)||
+ ''||pxs.sid||' | '||CHR(10)||
+ ''||pxs.serial#||' | '||CHR(10)||
+ ''||NVL(pxp.pid, pro.pid)||' | '||CHR(10)||
+ ''||NVL(pxp.spid, pro.spid)||' | '||CHR(10)||
+ ''||pxs.server_group||' | '||CHR(10)||
+ ''||pxs.server_set||' | '||CHR(10)||
+ ''||pxs.server#||' | '||CHR(10)||
+ ''||pxs.degree||' | '||CHR(10)||
+ ''||pxs.req_degree||' | '||CHR(10)||
+ ''||swt.event||' | '||CHR(10)||
+ ''||ses.sql_id||' | '||CHR(10)||
+ ''||ses.sql_child_number||' | '||CHR(10)||
+ ''||ses.resource_consumer_group||' | '||CHR(10)||
+ ''||ses.module||' | '||CHR(10)||
+ ''||ses.action||' | '||CHR(10)
+ line
+ FROM gv$px_session pxs,
+ gv$px_process pxp,
+ gv$session ses,
+ gv$process pro,
+ gv$session_wait swt
+ WHERE pxp.inst_id(+) = pxs.inst_id
+ AND pxp.sid(+) = pxs.sid
+ AND pxp.serial#(+) = pxs.serial#
+ AND ses.inst_id(+) = pxs.inst_id
+ AND ses.sid(+) = pxs.sid
+ AND ses.serial#(+) = pxs.serial#
+ AND ses.saddr(+) = pxs.saddr
+ AND pro.inst_id(+) = ses.inst_id
+ AND pro.addr(+) = ses.paddr
+ AND swt.inst_id(+) = ses.inst_id
+ AND swt.sid(+) = ses.sid
+ ORDER BY
+ pxs.inst_id,
+ pxs.qcsid,
+ pxs.qcserial# NULLS FIRST,
+ pxp.server_name NULLS FIRST ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO QC SID |
+PRO Server Name |
+PRO SID |
+PRO Serial# |
+PRO PID |
+PRO SPID |
+PRO Server Group |
+PRO Server Set |
+PRO Server# |
+PRO Degree |
+PRO Req Degree |
+PRO Wait Event |
+PRO SQL_ID |
+PRO Child# |
+PRO Resource Consumer Group |
+PRO Module |
+PRO Action |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * services
+ *
+ * ------------------------- */
+PRO Services
+PRO
+PRO Collected from GV$SERVICES.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Name |
+PRO Network Name |
+PRO Creation Date |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.name||' | '||CHR(10)||
+ ''||v.network_name||' | '||CHR(10)||
+ ''||TO_CHAR(v.creation_date, 'YYYY-MM-DD/HH24:MI:SS')||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ name,
+ network_name,
+ creation_date
+ FROM gv$services
+ ORDER BY
+ inst_id,
+ name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Name |
+PRO Network Name |
+PRO Creation Date |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * 11g io calibration results
+ *
+ * ------------------------- */
+PRO I/O Calibration Results
+PRO
+PRO Collected from DBA_RSRC_IO_CALIBRATE.
+PRO Note: Ignore possible errors about dba_rsrc_io_calibrate on 10g:
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Start Time |
+PRO End Time |
+PRO Max IO per sec |
+PRO Max MB per sec |
+PRO Max MB per sec per proc |
+PRO Latency |
+PRO Physical Disks |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||start_time||' | '||CHR(10)||
+ ''||end_time||' | '||CHR(10)||
+ ''||max_iops||' | '||CHR(10)||
+ ''||max_mbps||' | '||CHR(10)||
+ ''||max_pmbps||' | '||CHR(10)||
+ ''||latency||' | '||CHR(10)||
+ ''||num_physical_disks||' | '||CHR(10)||
+ '
'
+ FROM dba_rsrc_io_calibrate;
+
+PRO
+PRO
+PRO # |
+PRO Start Time |
+PRO End Time |
+PRO Max IO per sec |
+PRO Max MB per sec |
+PRO Max MB per sec per proc |
+PRO Latency |
+PRO Physical Disks |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * os stats
+ *
+ * ------------------------- */
+PRO Operating System Statistics
+PRO
+PRO Collected from GV$OSSTAT.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM gv$osstat ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * system statitics
+ *
+ * ------------------------- */
+PRO System Statistics
+PRO
+PRO Collected from SYS.AUX_STATS$.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Name |
+PRO Value |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.pname||' | '||CHR(10)||
+ ''||v.pval1||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ pname,
+ pval1
+ FROM sys.aux_stats$
+ WHERE sname = 'SYSSTATS_MAIN'
+ ORDER BY
+ pname ) v;
+
+PRO
+PRO
+PRO # |
+PRO Name |
+PRO Value |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * system statitics history
+ *
+ * ------------------------- */
+PRO System Statistics History
+PRO
+PRO Collected from SYS.WRI$_OPTSTAT_AUX_HISTORY.
+PRO This section includes data captured by AWR.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Save Time |
+PRO Name |
+PRO Value |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||TO_CHAR(v.savtime, 'YYYY-MM-DD/HH24:MI:SS.FF6')||' | '||CHR(10)||
+ ''||v.pname||' | '||CHR(10)||
+ ''||v.pval1||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ savtime,
+ pname,
+ pval1
+ FROM sys.wri$_optstat_aux_history
+ WHERE :license IN ('T', 'D')
+ AND sname = 'SYSSTATS_MAIN'
+ ORDER BY
+ savtime DESC,
+ pname ) v;
+
+PRO
+PRO
+PRO # |
+PRO Save Time |
+PRO Name |
+PRO Value |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * sgastat
+ *
+ * ------------------------- */
+PRO System Global Area (SGA) Statistics
+PRO
+PRO Collected from GV$SGASTAT.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Pool |
+PRO Name |
+PRO Bytes |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.pool||' | '||CHR(10)||
+ ''||v.name||' | '||CHR(10)||
+ ''||v.bytes||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ pool,
+ name,
+ bytes
+ FROM gv$sgastat
+ ORDER BY
+ inst_id,
+ pool,
+ name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Pool |
+PRO Name |
+PRO Bytes |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * awr sgastat
+ *
+ * ------------------------- */
+PRO System Global Area (SGA) Statistics History
+PRO
+PRO Collected from DBA_HIST_SGASTAT.
+PRO This section includes data captured by AWR.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Pool |
+PRO Name |
+PRO Min Bytes |
+PRO Max Bytes |
+PRO Avg Bytes |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||instance_number||' | '||CHR(10)||
+ ''||pool||' | '||CHR(10)||
+ ''||name||' | '||CHR(10)||
+ ''||min_bytes||' | '||CHR(10)||
+ ''||max_bytes||' | '||CHR(10)||
+ ''||avg_bytes||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ instance_number,
+ pool,
+ name,
+ MIN(bytes) min_bytes,
+ MAX(bytes) max_bytes,
+ ROUND(AVG(bytes)) avg_bytes
+ FROM dba_hist_sgastat
+ WHERE :license IN ('T', 'D')
+ GROUP BY
+ instance_number,
+ pool,
+ name
+ ORDER BY
+ instance_number,
+ pool,
+ name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Pool |
+PRO Name |
+PRO Min Bytes |
+PRO Max Bytes |
+PRO Avg Bytes |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * system parameters
+ *
+ * ------------------------- */
+PRO System Parameters with Non-Default or Modified Values
+PRO
+PRO Collected from GV$SYSTEM_PARAMETER2 where isdefault = 'FALSE' OR ismodified != 'FALSE'.
+PRO "Is Default" = FALSE means the parameter was set in the spfile.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Name |
+PRO Inst |
+PRO Ord |
+PRO Is Default |
+PRO Is Modified |
+PRO Value |
+PRO Display Value |
+PRO Description |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT /* ^^script..sql System Parameters */
+ CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.name||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.ordinal||' | '||CHR(10)||
+ ''||v.isdefault||' | '||CHR(10)||
+ ''||v.ismodified||' | '||CHR(10)||
+ ''||v.value||' | '||CHR(10)||
+ ''||DECODE(v.display_value, v.value, NULL, v.display_value)||' | '||CHR(10)||
+ ''||v.description||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */ *
+ FROM gv$system_parameter2
+ WHERE (isdefault = 'FALSE' OR ismodified <> 'FALSE')
+ ORDER BY
+ name,
+ inst_id,
+ ordinal ) v;
+
+PRO
+PRO
+PRO # |
+PRO Name |
+PRO Inst |
+PRO Ord |
+PRO Is Default |
+PRO Is Modified |
+PRO Value |
+PRO Display Value |
+PRO Description |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * instance parameters
+ *
+ * ------------------------- */
+PRO Instance Parameters
+PRO
+PRO System Parameters collected from V$SYSTEM_PARAMETER2 for Instance number ^^instance_number..
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Name |
+PRO Ord |
+PRO Is Default |
+PRO Is Modified |
+PRO Value |
+PRO Display Value |
+PRO Description |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT /* ^^script..sql System Parameters */
+ CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.name||' | '||CHR(10)||
+ ''||v.ordinal||' | '||CHR(10)||
+ ''||v.isdefault||' | '||CHR(10)||
+ ''||v.ismodified||' | '||CHR(10)||
+ ''||v.value||' | '||CHR(10)||
+ ''||DECODE(v.display_value, v.value, NULL, v.display_value)||' | '||CHR(10)||
+ ''||v.description||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */ *
+ FROM v$system_parameter2
+ ORDER BY
+ name,
+ ordinal ) v;
+
+PRO
+PRO
+PRO # |
+PRO Name |
+PRO Ord |
+PRO Is Default |
+PRO Is Modified |
+PRO Value |
+PRO Display Value |
+PRO Description |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * 11g sql monitor
+ *
+ * ------------------------- */
+PRO SQL Monitor
+PRO
+PRO Collected from GV$SQL_MONITOR where process_name = 'ora' and px_servers_requested > 1.
+PRO This section includes data from the Oracle Tuning pack.
+PRO Note: Ignore possible errors about gv$sql_monitor on 10g:
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Status |
+PRO First Refresh |
+PRO Last Refresh |
+PRO SQL_ID |
+PRO Plan Hash Value |
+PRO PX Max DOP |
+PRO PX Max DOP Inst |
+PRO PX Servers Requested |
+PRO PX Servers Allocated |
+PRO Elapsed Time (secs) |
+PRO Queuing Time (secs) |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT /* ^^script..sql SQL Monitor */
+ CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||v.status||' | '||CHR(10)||
+ ''||TO_CHAR(v.first_refresh_time, 'YYYY-MM-DD/HH24:MI:SS')||' | '||CHR(10)||
+ ''||TO_CHAR(v.last_refresh_time, 'YYYY-MM-DD/HH24:MI:SS')||' | '||CHR(10)||
+ ''||v.sql_id||' | '||CHR(10)||
+ ''||v.sql_plan_hash_value||' | '||CHR(10)||
+ ''||v.px_maxdop||' | '||CHR(10)||
+ ''||v.px_maxdop_instances||' | '||CHR(10)||
+ ''||v.px_servers_requested||' | '||CHR(10)||
+ ''||v.px_servers_allocated||' | '||CHR(10)||
+ ''||TO_CHAR(ROUND(v.elapsed_time / 1e6, 3), '99999999999990D990')||' | '||CHR(10)||
+ ''||TO_CHAR(ROUND(v.queuing_time / 1e6, 3), '99999999999990D990')||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */ *
+ FROM gv$sql_monitor
+ WHERE :license = 'T'
+ AND process_name = 'ora'
+ AND px_servers_requested > 1
+ ORDER BY
+ inst_id,
+ status,
+ first_refresh_time ) v;
+
+PRO
+PRO
+PRO # |
+PRO Inst |
+PRO Status |
+PRO First Refresh |
+PRO Last Refresh |
+PRO SQL_ID |
+PRO Plan Hash Value |
+PRO PX Max DOP |
+PRO PX Max DOP Inst |
+PRO PX Servers Requested |
+PRO PX Servers Allocated |
+PRO Elapsed Time (secs) |
+PRO Queuing Time (secs) |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * version cursor sharing
+ *
+ * ------------------------- */
+PRO Version Count as per Cursor Sharing
+PRO
+PRO Collected from GV$SQL_SHARED_CURSOR.
+PRO
+PRO
+PRO
+PRO
+PRO Inst |
+PRO Between 1 and 4 |
+PRO Between 5 and 8 |
+PRO Between 9 and 16 |
+PRO Between 17 and 32 |
+PRO Between 33 and 64 |
+PRO Between 65 and 128 |
+PRO Between 129 and 256 |
+PRO Between 257 and 512 |
+PRO Between 513 and 1024 |
+PRO Between 1025 and 2048 |
+PRO More Than 2048 |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+SELECT /* ^^script..sql Version Count as per Cursor Sharing */
+ CHR(10)||''||CHR(10)||
+ ''||v.inst_id||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 1 AND 4 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 5 AND 8 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 9 AND 16 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 17 AND 32 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 33 AND 64 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 65 AND 128 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 129 AND 256 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 257 AND 512 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 513 AND 1024 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions BETWEEN 1025 AND 2048 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ ''||SUM(CASE WHEN v.versions >= 2048 THEN 1 ELSE 0 END)||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ sql_id,
+ COUNT(*) versions
+ FROM gv$sql_shared_cursor
+ GROUP BY
+ inst_id, sql_id ) v
+ GROUP BY
+ v.inst_id
+ ORDER BY
+ v.inst_id;
+
+PRO
+PRO
+PRO Inst |
+PRO Between 1 and 4 |
+PRO Between 5 and 8 |
+PRO Between 9 and 16 |
+PRO Between 17 and 32 |
+PRO Between 33 and 64 |
+PRO Between 65 and 128 |
+PRO Between 129 and 256 |
+PRO Between 257 and 512 |
+PRO Between 513 and 1024 |
+PRO Between 1025 and 2048 |
+PRO More Than 2048 |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * cursor sharing reason
+ *
+ * ------------------------- */
+PRO Cursor Sharing and Reason
+PRO
+PRO Collected from GV$SQL_SHARED_CURSOR.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Reason |
+PRO Inst |
+PRO Cursors |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+@sql_shared_cursor.sql;
+
+PRO
+PRO
+PRO # |
+PRO Reason |
+PRO Inst |
+PRO Cursors |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * footer
+ *
+ * ------------------------- */
+PRO
+SELECT '' FROM dual;
+PRO
+PRO ^^mos_doc. ^^method. ^^doc_ver. ^^time_stamp2.
+PRO
+PRO
+
+SPO OFF;
+
+/**************************************************************************************************/
+
+/* -------------------------
+ *
+ * dop report
+ *
+ * ------------------------- */
+
+-- setup to produce report
+SET ECHO OFF FEED OFF VER OFF SHOW OFF HEA OFF LIN 2000 NEWP NONE PAGES 0 NUM 20 LONG 2000000 LONGC 2000 SQLC MIX TAB ON TRIMS ON TI OFF TIMI OFF ARRAY 100 NUMF "" SQLP SQL> SUF sql BLO . RECSEP OFF APPI OFF AUTOT OFF;
+
+/* -------------------------
+ *
+ * heading
+ *
+ * ------------------------- */
+SPO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._dop.html;
+
+PRO
+PRO
+PRO
+PRO
+PRO
+PRO
+PRO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._dop.html
+PRO
+
+PRO
+PRO
+
+PRO
+PRO
+PRO ^^mos_doc. ^^method.
+PRO ^^doc_ver. Report: ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._dop.html
+PRO
+
+PRO
+PRO License : ^^input_license.
+PRO RDBMS : ^^rdbms_version.
+PRO Platform : ^^platform.
+PRO Instance : ^^instance_number.
+PRO CPU Count : ^^sys_cpu.
+PRO Block Size: ^^sys_db_block_size.
+PRO OFE : ^^sys_ofe.
+PRO DYN_SAMP : ^^sys_ds.
+PRO EBS : "^^is_ebs."
+PRO SIEBEL : "^^is_siebel."
+PRO PSFT : "^^is_psft."
+PRO Date : ^^time_stamp2.
+PRO
+
+PRO
+
+/* -------------------------
+ *
+ * tables with dop <> 1
+ *
+ * ------------------------- */
+PRO Tables with non-default DOP
+PRO
+PRO Collected from DBA_TABLES where degree != 1.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Owner |
+PRO Table |
+PRO DOP |
+PRO Inst |
+PRO Blocks |
+PRO MB |
+PRO GB |
+PRO Part |
+PRO Temp |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+WITH
+tables AS (
+SELECT /*+ MATERIALIZE */
+ t.owner,
+ t.table_name,
+ TRIM(t.degree) table_degree,
+ TRIM(t.instances) table_instances,
+ t.blocks,
+ ROUND(t.blocks * ^^sys_db_block_size. / 1e6) tab_mb,
+ ROUND(t.blocks * ^^sys_db_block_size. / 1e9) tab_gb,
+ t.partitioned tab_part,
+ t.temporary
+ FROM dba_tables t
+ WHERE t.degree IS NOT NULL
+ AND TRIM(t.degree) <> '1'
+)
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.owner||' | '||CHR(10)||
+ ''||v.table_name||' | '||CHR(10)||
+ ''||v.table_degree||' | '||CHR(10)||
+ ''||v.table_instances||' | '||CHR(10)||
+ ''||v.blocks||' | '||CHR(10)||
+ ''||v.tab_mb||' | '||CHR(10)||
+ ''||v.tab_gb||' | '||CHR(10)||
+ ''||v.tab_part||' | '||CHR(10)||
+ ''||v.temporary||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ *
+ FROM tables
+ ORDER BY
+ owner,
+ table_name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Owner |
+PRO Table |
+PRO DOP |
+PRO Inst |
+PRO Blocks |
+PRO MB |
+PRO GB |
+PRO Part |
+PRO Temp |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * tables dop <> indexes dop
+ *
+ * ------------------------- */
+PRO Tables and Indexes with DOP mismatch
+PRO
+PRO Collected from DBA_TABLES and DBA_INDEXES where t.degree != i.degree.
+PRO
+PRO
+PRO
+PRO
+PRO # |
+PRO Owner |
+PRO Table |
+PRO DOP |
+PRO Inst |
+PRO Blocks |
+PRO MB |
+PRO GB |
+PRO Part |
+PRO Temp |
+PRO Index |
+PRO Type |
+PRO DOP |
+PRO Inst |
+PRO Leaf Blocks |
+PRO MB |
+PRO GB |
+PRO Part |
+PRO
+PRO
+SELECT '' FROM dual;
+PRO
+
+WITH
+tables_n_indexes AS (
+SELECT /*+ MATERIALIZE */
+ t.owner,
+ t.table_name,
+ TRIM(t.degree) table_degree,
+ TRIM(t.instances) table_instances,
+ t.blocks,
+ ROUND(t.blocks * ^^sys_db_block_size. / 1e6) tab_mb,
+ ROUND(t.blocks * ^^sys_db_block_size. / 1e9) tab_gb,
+ t.partitioned tab_part,
+ t.temporary,
+ i.index_name,
+ i.index_type,
+ TRIM(i.degree) index_degree,
+ TRIM(i.instances) index_instances,
+ i.leaf_blocks,
+ ROUND(i.leaf_blocks * ^^sys_db_block_size. / 1e6) idx_mb,
+ ROUND(i.leaf_blocks * ^^sys_db_block_size. / 1e9) idx_gb,
+ i.partitioned idx_part
+ FROM dba_tables t,
+ dba_indexes i
+ WHERE t.degree IS NOT NULL
+ AND i.table_owner = t.owner
+ AND i.table_name = t.table_name
+ AND i.table_type = 'TABLE'
+ AND i.index_type <> 'LOB'
+ AND i.degree IS NOT NULL
+ AND TRIM(i.degree) <> TRIM(t.degree)
+)
+SELECT CHR(10)||''||CHR(10)||
+ ''||ROWNUM||' | '||CHR(10)||
+ ''||v.owner||' | '||CHR(10)||
+ ''||v.table_name||' | '||CHR(10)||
+ ''||v.table_degree||' | '||CHR(10)||
+ ''||v.table_instances||' | '||CHR(10)||
+ ''||v.blocks||' | '||CHR(10)||
+ ''||v.tab_mb||' | '||CHR(10)||
+ ''||v.tab_gb||' | '||CHR(10)||
+ ''||v.tab_part||' | '||CHR(10)||
+ ''||v.temporary||' | '||CHR(10)||
+ ''||v.index_name||' | '||CHR(10)||
+ ''||v.index_type||' | '||CHR(10)||
+ ''||v.index_degree||' | '||CHR(10)||
+ ''||v.index_instances||' | '||CHR(10)||
+ ''||v.leaf_blocks||' | '||CHR(10)||
+ ''||v.idx_mb||' | '||CHR(10)||
+ ''||v.idx_gb||' | '||CHR(10)||
+ ''||v.idx_part||' | '||CHR(10)||
+ '
'
+ FROM (
+SELECT /*+ NO_MERGE */
+ *
+ FROM tables_n_indexes
+ ORDER BY
+ owner,
+ table_name,
+ index_name ) v;
+
+PRO
+PRO
+PRO # |
+PRO Owner |
+PRO Table |
+PRO DOP |
+PRO Inst |
+PRO Blocks |
+PRO MB |
+PRO GB |
+PRO Part |
+PRO Temp |
+PRO Index |
+PRO Type |
+PRO DOP |
+PRO Inst |
+PRO Leaf Blocks |
+PRO MB |
+PRO GB |
+PRO Part |
+PRO
+PRO
+PRO
+PRO
+
+/* -------------------------
+ *
+ * footer
+ *
+ * ------------------------- */
+PRO
+SELECT '' FROM dual;
+PRO
+PRO ^^mos_doc. ^^method. ^^doc_ver. ^^time_stamp2.
+PRO
+PRO
+
+SPO OFF;
+
+/**************************************************************************************************/
+
+/* -------------------------
+ *
+ * rsc report
+ *
+ * ------------------------- */
+
+-- setup to produce report
+SET ECHO OFF FEED OFF VER OFF SHOW OFF HEA OFF LIN 2000 NEWP NONE PAGES 0 NUM 20 LONG 2000000 LONGC 2000 SQLC MIX TAB ON TRIMS ON TI OFF TIMI OFF ARRAY 100 NUMF "" SQLP SQL> SUF sql BLO . RECSEP OFF APPI OFF AUTOT OFF;
+
+-- default date formats
+ALTER SESSION SET nls_date_format = 'YYYY-MM-DD/HH24:MI:SS';
+ALTER SESSION SET nls_timestamp_format = 'YYYY-MM-DD/HH24:MI:SS.FF';
+ALTER SESSION SET nls_timestamp_tz_format = 'YYYY-MM-DD/HH24:MI:SS.FF TZH:TZM';
+
+/* -------------------------
+ *
+ * heading
+ *
+ * ------------------------- */
+SPO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._rscr.html;
+
+PRO
+PRO
+PRO
+PRO
+PRO
+PRO
+PRO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._rscr.html
+PRO
+
+PRO
+PRO
+
+PRO
+PRO
+PRO ^^mos_doc. ^^method.
+PRO ^^doc_ver. Report: ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._rscr.html
+PRO
+
+PRO
+PRO License : ^^input_license.
+PRO RDBMS : ^^rdbms_version.
+PRO Platform : ^^platform.
+PRO Instance : ^^instance_number.
+PRO CPU Count : ^^sys_cpu.
+PRO Block Size: ^^sys_db_block_size.
+PRO OFE : ^^sys_ofe.
+PRO DYN_SAMP : ^^sys_ds.
+PRO EBS : "^^is_ebs."
+PRO SIEBEL : "^^is_siebel."
+PRO PSFT : "^^is_psft."
+PRO Date : ^^time_stamp2.
+PRO
+
+PRO
+
+/* -------------------------
+ *
+ * dba_users
+ *
+ * ------------------------- */
+PRO Default Resource Consumer Group and Profile per User
+PRO
+PRO Collected from DBA_USERS.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (
+SELECT /*+ NO_MERGE */
+ username,
+ initial_rsrc_consumer_group,
+ profile
+ FROM dba_users
+ ORDER BY
+ username ) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_profiles
+ *
+ * ------------------------- */
+PRO Resource Profiles
+PRO
+PRO Collected from DBA_PROFILES.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_profiles ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * gv$session
+ *
+ * ------------------------- */
+PRO Sessions per Resource Consumer Group
+PRO
+PRO Collected from GV$SESSION.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (
+SELECT /*+ NO_MERGE */
+ inst_id,
+ type,
+ username,
+ status,
+ resource_consumer_group,
+ COUNT(*)
+ FROM gv$session
+ GROUP BY
+ inst_id,
+ type,
+ username,
+ status,
+ resource_consumer_group
+ ORDER BY
+ inst_id,
+ type,
+ username,
+ status,
+ resource_consumer_group ) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * gv$rsrc_plan
+ *
+ * ------------------------- */
+PRO Active Resource Plans
+PRO
+PRO Collected from GV$RSRC_PLAN.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM gv$rsrc_plan ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * gv$rsrc_plan_history
+ *
+ * ------------------------- */
+PRO Active Resource Plans History
+PRO
+PRO Collected from GV$RSRC_PLAN_HISTORY.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM gv$rsrc_plan_history ORDER BY 1, 2, 3, 4, 5) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * gv$rsrc_consumer_group
+ *
+ * ------------------------- */
+PRO Active Resource Consumer Groups
+PRO
+PRO Collected from GV$RSRC_CONSUMER_GROUP.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM gv$rsrc_consumer_group ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * gv$rsrc_cons_group_history
+ *
+ * ------------------------- */
+PRO Active Resource Consumer Groups History
+PRO
+PRO Collected from GV$RSRC_CONS_GROUP_HISTORY.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM gv$rsrc_cons_group_history ORDER BY 1, 2, 3, 4) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_rsrc_plans
+ *
+ * ------------------------- */
+PRO Resource Plans
+PRO
+PRO Collected from DBA_RSRC_PLANS.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_rsrc_plans ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_rsrc_consumer_groups
+ *
+ * ------------------------- */
+PRO Resource Consumer Groups
+PRO
+PRO Collected from DBA_RSRC_CONSUMER_GROUPS.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_rsrc_consumer_groups ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_rsrc_plan_directives
+ *
+ * ------------------------- */
+PRO Resource Plan Directives
+PRO
+PRO Collected from DBA_RSRC_PLAN_DIRECTIVES.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_rsrc_plan_directives ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_rsrc_consumer_group_privs
+ *
+ * ------------------------- */
+PRO Resource Consumer Group Privileges
+PRO
+PRO Collected from DBA_RSRC_CONSUMER_GROUP_PRIVS.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_rsrc_consumer_group_privs ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_rsrc_group_mappings
+ *
+ * ------------------------- */
+PRO Resource Group Mappings
+PRO
+PRO Collected from DBA_RSRC_GROUP_MAPPINGS.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_rsrc_group_mappings ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+/* -------------------------
+ *
+ * dba_rsrc_mapping_priority
+ *
+ * ------------------------- */
+PRO Resource Mapping Priority
+PRO
+PRO Collected from DBA_RSRC_MAPPING_PRIORITY.
+PRO
+
+SET HEA ON PAGES 50 MARK HTML ON TABLE "" SPOOL OFF;
+SELECT ROWNUM "#", v.* FROM (SELECT /*+ NO_MERGE */ * FROM dba_rsrc_mapping_priority ORDER BY 1, 2, 3) v;
+SET HEA OFF PAGES 0 MARK HTML OFF;
+
+
+/* -------------------------
+ *
+ * footer
+ *
+ * ------------------------- */
+PRO
+SELECT '' FROM dual;
+PRO
+PRO ^^mos_doc. ^^method. ^^doc_ver. ^^time_stamp2.
+PRO
+PRO
+
+SPO OFF;
+
+/**************************************************************************************************/
+
+/* -------------------------
+ *
+ * 11g sql monitor report
+ *
+ * ------------------------- */
+PRO SQL Monitor Report
+PRO
+SELECT TO_CHAR(SYSDATE, 'YYYY-MM-DD/HH24:MI:SS') FROM dual;
+PRO Please Wait
+
+SPO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._monitor.sql;
+
+DECLARE
+ l_count NUMBER := 0;
+ TYPE mon_rt IS RECORD (
+ sql_id VARCHAR2(13),
+ status VARCHAR2(4000),
+ elapsed_time NUMBER,
+ queuing_time NUMBER );
+ mon_rec mon_rt;
+ mon_cv SYS_REFCURSOR;
+BEGIN
+ IF :license = 'T' AND '^^rdbms_version.' >= '11.2' THEN
+ DBMS_OUTPUT.PUT_LINE('-- Generating up to ^^monitor_reports. SQL Monitor Reports for PX statements.');
+ DBMS_OUTPUT.PUT_LINE('VAR mon CLOB;');
+ DBMS_OUTPUT.PUT_LINE('VAR sql_id VARCHAR2(13);');
+ DBMS_OUTPUT.PUT_LINE('SET ECHO OFF FEED OFF VER OFF SHOW OFF HEA OFF LIN 2000 NEWP NONE PAGES 0 NUM 20 LONG 2000000 LONGC 2000 SQLC MIX TAB ON TRIMS ON TI OFF TIMI OFF ARRAY 100 NUMF "" SQLP SQL> SUF sql BLO . RECSEP OFF APPI OFF AUTOT OFF;');
+
+ -- cursor variable to avoid error on 10g since v$sql_monitor didn't exist then
+ OPEN mon_cv FOR
+ 'SELECT sql_id, '||
+ ' MIN(DECODE(status, ''EXECUTING'', 1, ''QUEUED'', 2, 3)) status, '||
+ ' MAX(elapsed_time) elapsed_time, '||
+ ' MAX(queuing_time) queuing_time '||
+ ' FROM gv$sql_monitor /* 11g */ '||
+ ' WHERE process_name = ''ora'' '||
+ ' AND px_servers_requested > 1 '||
+ ' GROUP BY '||
+ ' sql_id '||
+ ' ORDER BY '||
+ ' 2, '||
+ ' 3 DESC, '||
+ ' 4 DESC ';
+ LOOP
+ FETCH mon_cv INTO mon_rec;
+ EXIT WHEN mon_cv%NOTFOUND;
+
+ l_count := l_count + 1;
+ IF l_count = ^^monitor_reports. THEN
+ EXIT; -- exits loop
+ END IF;
+
+ DBMS_OUTPUT.PUT_LINE('EXEC :sql_id := '''||mon_rec.sql_id||''';');
+ DBMS_OUTPUT.PUT_LINE('BEGIN');
+ DBMS_OUTPUT.PUT_LINE(' :mon := DBMS_SQLTUNE.REPORT_SQL_MONITOR (');
+ DBMS_OUTPUT.PUT_LINE(' sql_id => :sql_id,');
+ DBMS_OUTPUT.PUT_LINE(' report_level => ''ALL'',');
+ DBMS_OUTPUT.PUT_LINE(' type => ''ACTIVE'' );');
+ DBMS_OUTPUT.PUT_LINE('END;');
+ DBMS_OUTPUT.PUT_LINE('/');
+ DBMS_OUTPUT.PUT_LINE('SPO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._'||mon_rec.sql_id||'_^^time_stamp._monitor.html;');
+ DBMS_OUTPUT.PUT_LINE('SELECT :mon FROM DUAL;');
+ DBMS_OUTPUT.PUT_LINE('SPO OFF;');
+ END LOOP;
+ CLOSE mon_cv;
+ ELSE
+ DBMS_OUTPUT.PUT_LINE('-- SQL Monitor Reports are available on 11.2 and higher, and they are part of the Oracle Tuning pack.');
+ END IF;
+END;
+/
+
+SPO OFF;
+
+-- 11g
+@^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._monitor.sql
+
+/**************************************************************************************************/
+
+/* -------------------------
+ *
+ * wrap up
+ *
+ * ------------------------- */
+
+-- turing trace off
+ALTER SESSION SET SQL_TRACE = FALSE;
+ALTER SESSION SET STATISTICS_LEVEL = 'TYPICAL';
+
+-- get udump directory path
+COL udump_path NEW_V udump_path FOR A500;
+SELECT value||DECODE(INSTR(value, '/'), 0, '\', '/') udump_path FROM v$parameter2 WHERE name = 'user_dump_dest';
+
+-- tkprof for trace from execution of tool in case someone reports slow performance in tool
+HOS tkprof ^^udump_path.*^^script._^^unique_id.*.trc ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._tkprof_from_tool_exec.txt
+
+-- log zip
+HOS zip -mT ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._log.zip ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._tkprof_from_tool_exec.txt
+HOS zip -mT ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._log.zip sql_shared_cursor.sql
+HOS zip -mT ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._log.zip ^^script..log
+-- 11g
+HOS zip -mT ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._log.zip ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._monitor.sql
+
+-- 11g monitor zip
+HOS zip -mT ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp._monitor.zip ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._*^^time_stamp._monitor.*
+
+-- main zip
+HOS zip -mT ^^full_path.^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp..zip ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._*^^time_stamp.*
+
+-- end
+SET TERM ON ECHO OFF FEED 6 VER ON SHOW OFF HEA ON LIN 80 NEWP 1 PAGES 14 NUM 10 LONG 80 LONGC 80 SQLC MIX TAB ON TRIMS OFF TI OFF TIMI OFF ARRAY 15 NUMF "" SQLP SQL> SUF sql BLO . RECSEP WR APPI OFF SERVEROUT OFF AUTOT OFF;
+PRO
+PRO ^^method. zip file has been created:
+PRO ^^script._^^database_name_short._^^host_name_short._^^rdbms_version._^^time_stamp..zip.
+PRO
+CL COL;
+SET DEF ON;
+UNDEFINE 1 2 method script mos_doc doc_ver doc_date doc_link bug_link input_sql_id input_license input_event_10053 unique_id sql_id signature signaturef license event_10053 udump_path;