diff --git a/scripts/collector/oracle/collect-data.sh b/scripts/collector/oracle/collect-data.sh index 34f4cd0c..89258c8a 100755 --- a/scripts/collector/oracle/collect-data.sh +++ b/scripts/collector/oracle/collect-data.sh @@ -112,7 +112,9 @@ connectString="$1" OpVersion=$2 DiagPack=$(echo $3 | tr [[:upper:]] [[:lower:]]) manualUniqueId="${4}" -statsWindow=${5} +statsWindow="${5}" +statsStartDate="${6}" +statsDBID="${7}" if ! [ -x "$(command -v ${SQLPLUS})" ]; then echo "Could not find ${SQLPLUS} command. Source in environment and try again" @@ -120,11 +122,10 @@ if ! [ -x "$(command -v ${SQLPLUS})" ]; then exit 1 fi - ${SQLPLUS} -s /nolog << EOF SET DEFINE OFF connect ${connectString} -@${SQL_DIR}/op_collect.sql ${OpVersion} ${SQL_DIR} ${DiagPack} ${V_TAG} ${SQLOUTPUT_DIR} "${manualUniqueId}" ${statsWindow} +@${SQL_DIR}/op_collect.sql ${OpVersion} ${SQL_DIR} ${DiagPack} ${V_TAG} ${SQLOUTPUT_DIR} "${manualUniqueId}" "${statsWindow}" "${statsStartDate}" "${statsDBID}" exit; EOF @@ -240,6 +241,10 @@ fi if [ -f $OUTFILE ] then + if [ -f opdb__eoj__${V_FILE_TAG}.csv ] + then + cat opdb__eoj__${V_FILE_TAG}.csv + fi rm opdb*${V_FILE_TAG}.csv opdb*${V_FILE_TAG}*.log opdb*${V_FILE_TAG}*.txt fi @@ -325,6 +330,8 @@ statsSrc="" connStr="" manualUniqueId="" statsWindow=30 +statsStartDate="" +statsDBID="" if [[ $(($# & 1)) == 1 ]] ; then @@ -344,6 +351,8 @@ statsWindow=30 elif [[ "$1" == "--connectionStr" ]]; then connStr="${2}" elif [[ "$1" == "--manualUniqueId" ]]; then manualUniqueId="${2}" elif [[ "$1" == "--statsWindow" ]]; then statsWindow="${2}" + elif [[ "$1" == "--statsStartDate" ]]; then statsStartDate="${2}" # Experimental - Statspack only + elif [[ "$1" == "--statsDBID" ]]; then statsDBID="${2}" # Experimental - Statspack only else echo "Unknown parameter ${1}" printUsage @@ -359,16 +368,27 @@ statsWindow=30 if [[ "${statsSrc}" = "awr" ]]; then DIAGPACKACCESS="UseDiagnostics" + if [[ "$statsStartDate" != "" ]]; then + echo Parameter statsStartDate is not yet supported with AWR source. + exit 1 + fi + if [[ "$statsDBID" != "" ]]; then + echo Parameter statsDBID is not yet supported with AWR source. + exit 1 + fi elif [[ "${statsSrc}" = "statspack" ]] ; then DIAGPACKACCESS="NoDiagnostics" - else - echo No performance data will be collected. + else + echo User requested no performance data collection. DIAGPACKACCESS="nostatspack" fi - if [[ ${statsWindow} -ne 30 ]] && [[ ${statsWindow} -ne 7 ]] ; then + if [[ "${statsWindow}" == "" ]] ; then statsWindow=30 fi +# if [[ ${statsWindow} -ne 30 ]] && [[ ${statsWindow} -ne 7 ]] ; then +# statsWindow=30 +# fi if [[ "${connStr}" == "" ]] ; then if [[ "${hostName}" != "" && "${port}" != "" && "${databaseService}" != "" && "${collectionUserName}" != "" && "${collectionUserPass}" != "" ]] ; then @@ -405,6 +425,16 @@ statsWindow=30 # MAIN ############################################################################# +extractorVersion="$(getVersion)" + +echo "" +echo "===================================================================================" +echo "Database Migration Assessment Database Assessment Collector Version ${OpVersion}" +printExtractorVersion "${extractorVersion}" +echo "===================================================================================" +echo "" +echo "Connecting to database..." + connectString="${connStr}" sqlcmd_result=$(checkVersion "${connectString}" "${OpVersion}" | $GREP DMAFILETAG | cut -d '~' -f 2) if [[ "${sqlcmd_result}" = "" ]]; @@ -417,14 +447,6 @@ retval=$? # DIAGPACKACCESS="$2" -extractorVersion="$(getVersion)" - -echo "" -echo "===================================================================================" -echo "Database Migration Assessment Database Assessment Collector Version ${OpVersion}" -printExtractorVersion "${extractorVersion}" -echo "===================================================================================" - if [ $retval -eq 0 ]; then if [ "$(echo ${sqlcmd_result} | $GREP -E '(ORA-|SP2-)')" != "" ]; then echo "!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!" @@ -445,7 +467,7 @@ if [ $retval -eq 0 ]; then fi fi V_TAG="$(echo ${sqlcmd_result} | cut -d '|' -f2).csv"; export V_TAG - executeOP "${connectString}" ${OpVersion} ${DIAGPACKACCESS} "${manualUniqueId}" $statsWindow + executeOP "${connectString}" ${OpVersion} ${DIAGPACKACCESS} "${manualUniqueId}" "$statsWindow" "$statsStartDate" "$statsDBID" retval=$? if [ $retval -ne 0 ]; then createErrorLog $(echo ${V_TAG} | sed 's/.csv//g') diff --git a/scripts/collector/oracle/sql/extracts/archlogs.sql b/scripts/collector/oracle/sql/extracts/archlogs.sql index 59c5e0e1..797396d1 100644 --- a/scripts/collector/oracle/sql/extracts/archlogs.sql +++ b/scripts/collector/oracle/sql/extracts/archlogs.sql @@ -24,7 +24,7 @@ SELECT :v_pkey AS pkey, round(sum(blocks * block_size)/1024/1024) as mbytes, :v_dma_source_id AS DMA_SOURCE_ID, :v_manual_unique_id AS DMA_MANUAL_ID FROM gv$archived_log -WHERE first_time >= trunc(sysdate) - '&&dtrange' +WHERE first_time >= trunc(sysdate) - '&&dtrange' GROUP BY trunc(first_time), thread#, to_char(first_time, 'HH24'), dest_id ; spool off diff --git a/scripts/collector/oracle/sql/extracts/backups.sql b/scripts/collector/oracle/sql/extracts/backups.sql index 91d55818..78579c85 100644 --- a/scripts/collector/oracle/sql/extracts/backups.sql +++ b/scripts/collector/oracle/sql/extracts/backups.sql @@ -24,7 +24,7 @@ SELECT :v_pkey AS pkey, round(sum(output_bytes)/1024/1024) AS mbytes_out, :v_dma_source_id AS DMA_SOURCE_ID, :v_manual_unique_id AS DMA_MANUAL_ID FROM v$rman_backup_job_details a -WHERE start_time >= trunc(sysdate) - '&&dtrange' +WHERE start_time >= trunc(sysdate) - '&&dtrange' GROUP BY trunc(start_time), input_type, &v_a_con_id ; spool off diff --git a/scripts/collector/oracle/sql/extracts/dbsummary.sql b/scripts/collector/oracle/sql/extracts/dbsummary.sql index f1b76cee..62576b13 100644 --- a/scripts/collector/oracle/sql/extracts/dbsummary.sql +++ b/scripts/collector/oracle/sql/extracts/dbsummary.sql @@ -38,7 +38,7 @@ SELECT :v_pkey AS pkey, FROM (SELECT TRUNC(first_time) dia, COUNT(*) conta FROM v$log_history - WHERE first_time >= TRUNC(SYSDATE) - '&&dtrange' + WHERE first_time >= TRUNC(SYSDATE) - '&&dtrange' AND first_time < TRUNC(SYSDATE) GROUP BY TRUNC(first_time)), v$log) AS redo_gb_per_day, diff --git a/scripts/collector/oracle/sql/extracts/defines.sql b/scripts/collector/oracle/sql/extracts/defines.sql index ec1e68e9..4224c2df 100644 --- a/scripts/collector/oracle/sql/extracts/defines.sql +++ b/scripts/collector/oracle/sql/extracts/defines.sql @@ -41,16 +41,19 @@ prompt v_c_con_id = &v_c_con_id prompt v_h_con_id = &v_h_con_id prompt v_data_type_exp = &v_data_type_exp prompt v_db_container_col = &v_db_container_col -prompt v_dbid = &v_dbid -prompt v_dma_source_id = &v_dma_source_id -prompt v_dbname = &v_dbname -prompt v_dbparam_dflt_col = &v_dbparam_dflt_col -prompt v_dbversion = &v_dbversion -prompt v_dopluggable = &v_dopluggable -prompt v_editionable_col = &v_editionable_col -prompt v_hora = &v_hora -prompt v_host = &v_host -prompt v_inst = &v_inst +prompt v_dbid = &v_dbid +prompt v_statsDBIDRequested = &v_statsDBIDRequested +prompt v_statsDBID = &v_statsDBID +prompt v_dbname = &v_dbname +prompt v_dbparam_dflt_col = &v_dbparam_dflt_col +prompt v_dbversion = &v_dbversion +prompt v_dodiagnostics = &v_dodiagnostics +prompt v_dopluggable = &v_dopluggable +prompt v_editionable_col = &v_editionable_col +prompt v_hora = &v_hora +prompt v_host = &v_host +prompt v_info_prompt = &p_info_prompt +prompt v_inst = &v_inst prompt v_io_function_sql = &v_io_function_sql prompt v_is_container = &v_is_container prompt v_max_snapid = &v_max_snapid @@ -60,4 +63,8 @@ prompt v_umf_test = &v_umf_test prompt Applies to STATSPACK collections only: prompt v_max_snaptime = &v_max_snaptime prompt v_min_snaptime = &v_min_snaptime +prompt v_statsStartDate = &v_statsStartDate +prompt v_statsWindow = &v_statsWindow +prompt +SELECT 'v_dma_sourceid = ' || :v_dma_source_id FROM DUAL; spool off diff --git a/scripts/collector/oracle/sql/extracts/eoj.sql b/scripts/collector/oracle/sql/extracts/eoj.sql index 1a735310..8f564f69 100644 --- a/scripts/collector/oracle/sql/extracts/eoj.sql +++ b/scripts/collector/oracle/sql/extracts/eoj.sql @@ -16,4 +16,5 @@ -- This file intentionally has no extraction SQL. spool &outputdir/opdb__eoj__&v_tag prompt END_OF_DMA_COLLECTION +prompt &p_end_of_job_summary spool off diff --git a/scripts/collector/oracle/sql/extracts/statspack/awrhistcmdtypes.sql b/scripts/collector/oracle/sql/extracts/statspack/awrhistcmdtypes.sql index 5c818ed7..cc8c6ea5 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/awrhistcmdtypes.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/awrhistcmdtypes.sql @@ -21,8 +21,8 @@ prompt PKEY|CON_ID|HH|COMMAND_TYPE|CNT|AVG_BUFFER_GETS|AVG_ELASPED_TIME|AVG_ROWS WITH vcmdtype AS( SELECT :v_pkey AS pkey, 'N/A' AS con_id, - TO_CHAR(sn.snap_time, 'hh24') AS hh24, - ss.command_type, + TO_CHAR(snap_time, 'hh24') AS hh24, + command_type, COUNT(1) AS cnt, ROUND(AVG(delta_buffer_gets)) AS avg_buffer_gets, ROUND(AVG(delta_elapsed_time)) AS avg_elapsed_time, @@ -34,8 +34,10 @@ SELECT :v_pkey AS pkey, ROUND(AVG(delta_application_wait_time)) AS avg_apwait, ROUND(AVG(delta_concurrency_wait_time)) AS avg_ccwait, ROUND(AVG(delta_plsql_exec_time)) AS avg_plsexec_time, - aa.name AS command_name -FROM + name AS command_name +FROM +( SELECT ss.*, aa.name, sn.snap_time, sn.startup_time, sn.lag_startup_time + FROM ( select snap_id, dbid, instance_number, text_subset, old_hash_value, command_type, force_matching_signature, sql_id, s.executions, @@ -160,15 +162,20 @@ s.executions, 0) AS delta_java_exec_time From STATS$SQL_SUMMARY s ) ss - JOIN stats$snapshot sn + JOIN ( SELECT dbid, instance_number, snap_id, snap_time, startup_time, lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM stats$snapshot + WHERE snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND dbid = &&v_statsDBID + ) sn ON ss.dbid = sn.dbid AND ss.snap_id = sn.snap_id AND ss.instance_number = sn.instance_number LEFT OUTER join audit_actions aa ON ss.command_type = aa.action -WHERE sn.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + ) + WHERE startup_time = lag_startup_time GROUP BY :v_pkey, - 'N/A' , TO_CHAR(sn.snap_time, 'hh24'), ss.command_type, aa.name + 'N/A' , TO_CHAR(snap_time, 'hh24'), command_type, name ) SELECT pkey , con_id AS sp_con_id, hh24 , command_type , cnt , avg_buffer_gets , avg_elapsed_time , avg_rows_processed , avg_executions , avg_cpu_time , avg_iowait , avg_clwait , diff --git a/scripts/collector/oracle/sql/extracts/statspack/awrhistosstat.sql b/scripts/collector/oracle/sql/extracts/statspack/awrhistosstat.sql index b13abc78..3e8b11d0 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/awrhistosstat.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/awrhistosstat.sql @@ -57,7 +57,9 @@ WITH v_osstat_all OVER ( PARTITION BY s.dbid, s.instance_number, osname.STAT_NAME ORDER BY s.snap_id), - 0), 0) AS delta_value + 0), 0) AS delta_value, + snap.startup_time, + LAG(snap.startup_time) OVER (PARTITION BY snap.dbid, snap.instance_number, s.osstat_id ORDER BY snap.snap_time) AS lag_startup_time FROM STATS$OSSTAT s inner join STATS$SNAPSHOT snap ON s.snap_id = snap.snap_id @@ -65,8 +67,9 @@ WITH v_osstat_all AND s.dbid = snap.dbid inner join STATS$OSSTATNAME osname ON s.osstat_id = osname.osstat_id - WHERE snap.snap_time BETWEEN (SELECT max(snap_time) FROM STATS$SNAPSHOT WHERE snap_time < '&&v_min_snaptime' ) AND '&&v_max_snaptime' - AND s.dbid = '&&v_dbid') os ) , + WHERE snap.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND s.dbid = '&&v_statsDBID') os + WHERE startup_time = lag_startup_time) , vossummary AS ( SELECT :v_pkey AS pkey, dbid, diff --git a/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetrichist.sql b/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetrichist.sql index f8f8d3c2..0403c1ac 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetrichist.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetrichist.sql @@ -19,28 +19,30 @@ spool &outputdir/opdb__awrhistsysmetrichist__&v_tag prompt PKEY|DBID|INSTANCE_NUMBER|HOUR|METRIC_NAME|METRIC_UNIT|AVG_VALUE|MODE_VALUE|MEDIAN_VALUE|MIN_VALUE|MAX_VALUE|SUM_VALUE|PERC50|PERC75|PERC90|PERC95|PERC100|DMA_SOURCE_ID|DMA_MANUAL_ID WITH vsysmetric AS ( SELECT :v_pkey AS pkey, - hsm.dbid, - hsm.instance_number, - TO_CHAR(dhsnap.snap_time, 'hh24') hour, - hsm.name as metric_name, + dbid, + instance_number, + TO_CHAR(snap_time, 'hh24') hour, + name as metric_name, null as metric_unit, - ROUND(AVG(hsm.delta_value)) avg_value, - ROUND(STATS_MODE(hsm.delta_value)) mode_value, - ROUND(MEDIAN(hsm.delta_value)) median_value, - ROUND(MIN(hsm.delta_value)) min_value, - ROUND(MAX(hsm.delta_value)) max_value, - ROUND(SUM(hsm.delta_value)) sum_value, + ROUND(AVG(delta_value)) avg_value, + ROUND(STATS_MODE(delta_value)) mode_value, + ROUND(MEDIAN(delta_value)) median_value, + ROUND(MIN(delta_value)) min_value, + ROUND(MAX(delta_value)) max_value, + ROUND(SUM(delta_value)) sum_value, ROUND(PERCENTILE_CONT(0.5) - within GROUP (ORDER BY hsm.delta_value DESC)) AS "PERC50", + within GROUP (ORDER BY delta_value DESC)) AS "PERC50", ROUND(PERCENTILE_CONT(0.25) - within GROUP (ORDER BY hsm.delta_value DESC)) AS "PERC75", + within GROUP (ORDER BY delta_value DESC)) AS "PERC75", ROUND(PERCENTILE_CONT(0.10) - within GROUP (ORDER BY hsm.delta_value DESC)) AS "PERC90", + within GROUP (ORDER BY delta_value DESC)) AS "PERC90", ROUND(PERCENTILE_CONT(0.05) - within GROUP (ORDER BY hsm.delta_value DESC)) AS "PERC95", + within GROUP (ORDER BY delta_value DESC)) AS "PERC95", ROUND(PERCENTILE_CONT(0) - within GROUP (ORDER BY hsm.delta_value DESC)) AS "PERC100" -FROM ( + within GROUP (ORDER BY delta_value DESC)) AS "PERC100" +FROM +( SELECT hsm.*, dhsnap.snap_time, dhsnap.startup_time, dhsnap.lag_startup_time + FROM ( ( SELECT s.snap_id, s.dbid, s.instance_number, s.name, s.value, NVL( DECODE( @@ -50,25 +52,28 @@ FROM ( 0), 0) AS delta_value FROM perfstat.stats$sysstat s ) hsm - INNER JOIN stats$snapshot dhsnap + INNER JOIN ( SELECT dbid, instance_number, snap_id, snap_time, startup_time, lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM stats$snapshot + WHERE snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND dbid = &&v_statsDBID + ) dhsnap ON hsm.snap_id = dhsnap.snap_id AND hsm.instance_number = dhsnap.instance_number - AND hsm.dbid = dhsnap.dbid -WHERE dhsnap.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' -AND hsm.dbid = &&v_dbid + AND hsm.dbid = dhsnap.dbid) +WHERE startup_time = lag_startup_time) GROUP BY :v_pkey, - hsm.dbid, - hsm.instance_number, - TO_CHAR(dhsnap.snap_time, 'hh24'), - hsm.name -ORDER BY hsm.dbid, - hsm.instance_number, - hsm.name, - TO_CHAR(dhsnap.snap_time, 'hh24')) + dbid, + instance_number, + TO_CHAR(snap_time, 'hh24'), + name +ORDER BY dbid, + instance_number, + name, + TO_CHAR(snap_time, 'hh24')) SELECT pkey , dbid , instance_number , hour , metric_name , metric_unit , avg_value , mode_value , median_value , min_value , max_value , - sum_value , PERC50 , PERC75 , PERC90 , PERC95 , PERC100, - :v_dma_source_id AS DMA_SOURCE_ID, :v_manual_unique_id AS DMA_MANUAL_ID + sum_value , PERC50 , PERC75 , PERC90 , PERC95 , PERC100, + :v_dma_source_id AS DMA_SOURCE_ID, :v_manual_unique_id AS DMA_MANUAL_ID FROM vsysmetric; spool off COLUMN HOUR CLEAR diff --git a/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetricsumm.sql b/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetricsumm.sql index aa2e783b..d269378a 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetricsumm.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/awrhistsysmetricsumm.sql @@ -50,7 +50,9 @@ SELECT :v_pkey AS pkey, --hsm.AVERAGE+(2* CASE WHEN ( standard_deviation > (.999999999999999999999999999) AND standard_deviation < 1 ) -- AND ( MINVAL = 0 AND AVERAGE = MAXVAL ) then 0 else standard_deviation end ) "PERC95", AVG(value) OVER (PARTITION BY hsm.dbid, hsm.instance_number, TO_CHAR(dhsnap.snap_time, 'hh24') , hsm.name) + (2 * STDDEV (value) OVER (PARTITION BY hsm.dbid, hsm.instance_number, TO_CHAR(dhsnap.snap_time, 'hh24') , hsm.name)) AS "PERC95", - NULL "PERC100" + NULL "PERC100", + startup_time, + lag_startup_time FROM ( SELECT s.snap_id, s.dbid, s.instance_number, s.name, s.value, NVL( @@ -61,12 +63,16 @@ FROM ( 0), 0) AS delta_value FROM perfstat.stats$sysstat s ) hsm - INNER JOIN stats$snapshot dhsnap + INNER JOIN (SELECT dbid, instance_number, snap_id, snap_time, startup_time, + lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM stats$snapshot + WHERE snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND dbid = &&v_statsDBID + ) dhsnap ON hsm.snap_id = dhsnap.snap_id AND hsm.instance_number = dhsnap.instance_number AND hsm.dbid = dhsnap.dbid -WHERE dhsnap.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' -AND hsm.dbid = &&v_dbid), + ), vsysmetricsummperhour as ( SELECT pkey, hsm.dbid, @@ -91,6 +97,7 @@ vsysmetricsummperhour as ( ROUND(PERCENTILE_CONT(0) within GROUP (ORDER BY hsm.PERC95 DESC)) AS "PERC100" FROM vsysmetricsumm hsm + WHERE startup_time = lag_startup_time GROUP BY pkey, hsm.dbid, hsm.instance_number, diff --git a/scripts/collector/oracle/sql/extracts/statspack/awrsnapdetails.sql b/scripts/collector/oracle/sql/extracts/statspack/awrsnapdetails.sql index 14fcd037..67c07648 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/awrsnapdetails.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/awrsnapdetails.sql @@ -55,12 +55,12 @@ FROM ( ORDER BY s.snap_id), 0), 0) * 60 * 60 * 24 AS snaps_diff_secs, s.startup_time, - LAG(s.startup_time,1) OVER (partition by instance_number ORDER BY snap_time) as lag_startup_time + LAG(s.startup_time,1) OVER (partition by dbid, instance_number ORDER BY snap_time) as lag_startup_time FROM STATS$SNAPSHOT s WHERE s.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' - AND dbid = &&v_dbid + AND dbid = &&v_statsDBID order by s.snap_id ) - WHERE startup_time = lag_startup_time + WHERE startup_time = lag_startup_time -- Skip the first snap after a restart ) GROUP BY :v_pkey, dbid, instance_number, hour) SELECT pkey , dbid , instance_number , hour , min_snap_id , max_snap_id , min_begin_interval_time , diff --git a/scripts/collector/oracle/sql/extracts/statspack/dbahistsysstat.sql b/scripts/collector/oracle/sql/extracts/statspack/dbahistsysstat.sql index 8011546e..cba50a80 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/dbahistsysstat.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/dbahistsysstat.sql @@ -55,12 +55,16 @@ SELECT over ( PARTITION BY s.dbid, s.instance_number, g.name ORDER BY s.snap_id), - 0), 0) AS VALUE -FROM STATS$SNAPSHOT s, + 0), 0) AS VALUE, + startup_time, + lag_startup_time +FROM ( SELECT dbid, instance_number, snap_id, snap_time, startup_time, lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM STATS$SNAPSHOT + WHERE snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND dbid = '&&v_statsDBID' + ) s, STATS$SYSSTAT g WHERE s.snap_id = g.snap_id - AND s.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' - AND s.dbid = '&&v_dbid' AND s.instance_number = g.instance_number AND s.dbid = g.dbid AND (LOWER(name) LIKE '%db%time%' @@ -79,6 +83,7 @@ WHERE s.snap_id = g.snap_id -- or LOWER(name) LIKE '%lob%' or LOWER(name) LIKE 'user%') ) +WHERE startup_time = lag_startup_time GROUP BY :v_pkey, dbid, diff --git a/scripts/collector/oracle/sql/extracts/statspack/dbahistsystimemodel.sql b/scripts/collector/oracle/sql/extracts/statspack/dbahistsystimemodel.sql index bdff88ee..ee556c12 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/dbahistsystimemodel.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/dbahistsystimemodel.sql @@ -56,17 +56,22 @@ SELECT over ( PARTITION BY s.dbid, s.instance_number, n.stat_name ORDER BY s.snap_id), - 0), 0) AS value -FROM STATS$SNAPSHOT s, + 0), 0) AS value, + startup_time, + lag_startup_time +FROM ( SELECT dbid, instance_number, snap_id, snap_time, startup_time, lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM STATS$SNAPSHOT + WHERE snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND dbid = '&&v_statsDBID' + ) s, STATS$SYS_TIME_MODEL g, STATS$TIME_MODEL_STATNAME n WHERE s.snap_id = g.snap_id AND s.instance_number = g.instance_number AND s.dbid = g.dbid AND g.stat_id = n.stat_id - AND s.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' - AND s.dbid = '&&v_dbid' ) +WHERE startup_time = lag_startup_time GROUP BY :v_pkey, dbid, diff --git a/scripts/collector/oracle/sql/extracts/statspack/ioevents.sql b/scripts/collector/oracle/sql/extracts/statspack/ioevents.sql index ed14ec82..f51abb93 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/ioevents.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/ioevents.sql @@ -38,16 +38,20 @@ SELECT :v_pkey AS pkey, NVL(DECODE(GREATEST(sev.time_waited_micro, NVL(LAG(sev.time_waited_micro) OVER (PARTITION BY sev.dbid, sev.instance_number, sev.event ORDER BY sev.snap_id), 0)), sev.time_waited_micro, sev.time_waited_micro - LAG(sev.time_waited_micro) - OVER (PARTITION BY sev.dbid, sev.instance_number, sev.event ORDER BY sev.snap_id),0), 0) AS time_wa_us_delta_value + OVER (PARTITION BY sev.dbid, sev.instance_number, sev.event ORDER BY sev.snap_id),0), 0) AS time_wa_us_delta_value, + startup_time, + lag_startup_time FROM STATS$SYSTEM_EVENT sev - INNER JOIN stats$snapshot dhsnap + INNER JOIN (SELECT dbid, instance_number, snap_id, snap_time, startup_time, lag(startup_time) OVER(PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM stats$snapshot + WHERE snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + AND dbid = &&v_statsDBID + ) dhsnap ON sev.snap_id = dhsnap.snap_id AND sev.instance_number = dhsnap.instance_number AND sev.dbid = dhsnap.dbid INNER JOIN v$event_name en ON en.name = sev.event -WHERE dhsnap.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' -AND sev.dbid = &&v_dbid -AND en.wait_class IN ('User I/O', 'System I/O', 'Commit')), + AND en.wait_class IN ('User I/O', 'System I/O', 'Commit')), vpercev AS( SELECT pkey, dbid, @@ -68,6 +72,7 @@ SELECT pkey, PERCENTILE_CONT(0.00) within GROUP (ORDER BY time_wa_us_delta_value DESC) AS time_wa_us_delta_value_P100 FROM vrawev +WHERE startup_time = lag_startup_time GROUP BY pkey, dbid, instance_number, diff --git a/scripts/collector/oracle/sql/extracts/statspack/iofunction.sql b/scripts/collector/oracle/sql/extracts/statspack/iofunction.sql index d5bd6346..31219df5 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/iofunction.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/iofunction.sql @@ -61,16 +61,21 @@ SELECT :v_pkey AS pkey, NVL(DECODE(GREATEST(iof.wait_time, NVL(LAG(iof.wait_time) OVER (PARTITION BY iof.dbid, iof.instance_number, fn.function_name ORDER BY iof.snap_id), 0)), iof.wait_time, iof.wait_time - LAG(iof.wait_time) - OVER (PARTITION BY iof.dbid, iof.instance_number, fn.function_name ORDER BY iof.snap_id),0), 0) AS tot_watime_delta_value + OVER (PARTITION BY iof.dbid, iof.instance_number, fn.function_name ORDER BY iof.snap_id),0), 0) AS tot_watime_delta_value, + startup_time, + lag_startup_time FROM STATS$IOSTAT_FUNCTION iof - INNER JOIN STATS$SNAPSHOT snap + INNER JOIN ( SELECT dbid, instance_number, snap_time, snap_id, startup_time, lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM STATS$SNAPSHOT + WHERE dbid = &&v_statsDBID + AND snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + ) snap ON iof.snap_id = snap.snap_id AND iof.instance_number = snap.instance_number AND iof.dbid = snap.dbid INNER JOIN STATS$IOSTAT_FUNCTION_NAME fn ON fn.function_id = iof.function_id -WHERE snap.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' -AND snap.dbid = &&v_dbid), +), vperciof AS ( SELECT pkey, dbid, @@ -118,6 +123,7 @@ SELECT pkey, PERCENTILE_CONT(0.00) within GROUP (ORDER BY tot_watime_delta_value DESC) AS tot_watime_delta_value_P100 FROM vrawiof +WHERE startup_time = lag_startup_time GROUP BY pkey, dbid, instance_number, diff --git a/scripts/collector/oracle/sql/extracts/statspack/sqlstats.sql b/scripts/collector/oracle/sql/extracts/statspack/sqlstats.sql index 1ee8dec3..18e3673c 100644 --- a/scripts/collector/oracle/sql/extracts/statspack/sqlstats.sql +++ b/scripts/collector/oracle/sql/extracts/statspack/sqlstats.sql @@ -28,8 +28,8 @@ prompt PKEY|CON_ID|DBID|INSTANCE_NUMBER|FORCE_MATCHING_SIGNATURE|SQL_ID|TOTAL_EX WITH vsqlstat AS( SELECT :v_pkey AS pkey, 'N/A' AS con_id, - b.dbid, - b.instance_number, + dbid, + instance_number, to_char(force_matching_signature) force_matching_signature, min(sql_id) sql_id, ROUND(sum(executions)) total_executions, @@ -56,7 +56,8 @@ SELECT :v_pkey AS pkey, trunc(decode(sum(executions), 0, 0, sum(concurrency_wait_time)/sum(executions))) avg_ccwait_us, trunc(decode(sum(executions), 0, 0, sum(plsql_exec_time)/sum(executions))) avg_plsexec_us, trunc(decode(sum(executions), 0, 0, sum(java_exec_time)/sum(executions))) avg_javexec_us -FROM +FROM +( SELECT a.*, b.startup_time, b.lag_startup_time FROM ( select snap_id, dbid, instance_number, text_subset, old_hash_value, command_type, force_matching_signature, sql_id, s.executions, @@ -181,14 +182,17 @@ s.executions, 0) AS delta_java_exec_time From STATS$SQL_SUMMARY s ) a, - STATS$SNAPSHOT b + ( SELECT dbid, instance_number, snap_id, startup_time, lag(startup_time) OVER (PARTITION BY dbid, instance_number ORDER BY snap_time) AS lag_startup_time + FROM STATS$SNAPSHOT + WHERE dbid = &&v_statsDBID + AND snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' + ) b WHERE a.snap_id = b.snap_id AND a.instance_number = b.instance_number -AND a.dbid = b.dbid -AND b.snap_time BETWEEN '&&v_min_snaptime' AND '&&v_max_snaptime' -AND b.dbid = &&v_dbid +AND a.dbid = b.dbid) +WHERE startup_time = lag_startup_time GROUP BY :v_pkey, - b.dbid, b.instance_number, force_matching_signature + dbid, instance_number, force_matching_signature ORDER BY elapsed_time_total DESC) SELECT pkey , con_id AS sp_con_id , dbid , instance_number , force_matching_signature , sql_id , total_executions , total_px_servers_execs , elapsed_time_total , disk_reads_total , diff --git a/scripts/collector/oracle/sql/op_collect.sql b/scripts/collector/oracle/sql/op_collect.sql index d318ac13..0785ca7d 100644 --- a/scripts/collector/oracle/sql/op_collect.sql +++ b/scripts/collector/oracle/sql/op_collect.sql @@ -21,22 +21,14 @@ DEFINE v_dodiagnostics=&3 DEFINE v_tag=&4 DEFINE outputdir=&5 DEFINE v_manualUniqueId=&6 -DEFINE v_statsWindow=&7 +DEFINE v_statsWindow="&7" +DEFINE v_statsStartDate="&8" +DEFINE v_statsDBIDRequested="&9" DEFINE EXTRACTSDIR=&SQLDIR/extracts DEFINE AWRDIR=&EXTRACTSDIR/awr DEFINE STATSPACKDIR=&EXTRACTSDIR/statspack DEFINE TERMOUTOFF=OFF -prompt -prompt *********************************************************************************** -prompt -prompt !!! ATTENTION !!! -prompt -@&SQLDIR/prompt_&v_dodiagnostics -prompt -prompt -prompt *********************************************************************************** -prompt prompt Initializing Database Migration Assessment Collector... prompt @@ -94,5 +86,6 @@ set termout on prompt Step completed. prompt prompt Database Migration Assessment data successfully extracted. +prompt &p_end_of_job_summary prompt exit diff --git a/scripts/collector/oracle/sql/op_collect_init.sql b/scripts/collector/oracle/sql/op_collect_init.sql index 2f9e6700..93434d68 100644 --- a/scripts/collector/oracle/sql/op_collect_init.sql +++ b/scripts/collector/oracle/sql/op_collect_init.sql @@ -55,6 +55,7 @@ variable minsnap NUMBER; variable minsnaptime VARCHAR2(20); variable maxsnap NUMBER; variable maxsnaptime VARCHAR2(20); +variable firstsnaptime VARCHAR2(20); -- To handle collection from within a Dataguard standby variable umfflag VARCHAR2(100); @@ -81,6 +82,8 @@ variable b_io_function_sql VARCHAR2(20); variable v_dma_source_id VARCHAR2(100); variable v_manual_unique_id VARCHAR2(100); +variable v_end_of_job_summary VARCHAR2(200); +variable v_stats_source VARCHAR2(200); -- Session settings to support creating substitution variables for the scripts. column instnc new_value v_inst noprint @@ -95,6 +98,7 @@ column max_snaptime new_value v_max_snaptime noprint column umf_test new_value v_umf_test noprint --column p_dma_source_id new_value v_dma_source_id noprint column p_dbid new_value v_dbid noprint +column p_statsdbid new_value v_statsdbid noprint column p_tblprefix new_value v_tblprefix noprint column p_is_container new_value v_is_container noprint column p_dbparam_dflt_col new_value v_dbparam_dflt_col noprint @@ -112,6 +116,8 @@ column p_lob_part_dedup_col new_value v_lob_part_dedup_col noprint column p_lob_subpart_dedup_col new_value v_lob_subpart_dedup_col noprint column p_index_visibility new_value v_index_visibility noprint column p_io_function_sql new_value v_io_function_sql noprint +column end_of_job_summary new_value p_end_of_job_summary noprint +column stats_source new_value v_stats_source noprint -- Define some session info for the extraction -- BEGIN SELECT host_name hostnc, @@ -288,10 +294,10 @@ SELECT :b_compress_col AS p_compress_col FROM dual; DECLARE cnt NUMBER; BEGIN - SELECT SUM(cnt) INTO cnt FROM ( - SELECT count(1) FROM dba_views WHERE (view_name = 'DBA_HIST_IOSTAT_FUNCTION' AND '&v_dodiagnostics' = 'usediagnostics') + SELECT SUM(tabcnt) INTO cnt FROM ( + SELECT count(1) AS tabcnt FROM dba_views WHERE (view_name = 'DBA_HIST_IOSTAT_FUNCTION' AND '&v_dodiagnostics' = 'usediagnostics') UNION - SELECT count(1) FROM dba_tables WHERE (table_name ='STATS$IOSTAT_FUNCTION_NAME' AND '&v_dodiagnostics' = 'nodiagnostics' AND OWNER ='PERFSTAT') + SELECT count(1) AS tabcnt FROM dba_tables WHERE (table_name ='STATS$IOSTAT_FUNCTION_NAME' AND '&v_dodiagnostics' = 'nodiagnostics' AND OWNER ='PERFSTAT') ); IF (cnt > 0 ) THEN :b_io_function_sql := 'iofunction.sql'; ELSE @@ -329,7 +335,7 @@ FROM dual / -- Finally get the dbid from the determined source. -SELECT &v_umf_test p_dbid +SELECT TRIM(&v_umf_test) p_dbid , NVL('&&v_statsDBIDRequested', TRIM(&v_umf_test)) p_statsDBID FROM v$database / -- Get the DBID - END @@ -412,35 +418,40 @@ BEGIN IF '&v_dodiagnostics' = 'usediagnostics' THEN l_tab_name := 'DBA_HIST_SNAPSHOT'; l_col_name := 'begin_interval_time'; + :v_stats_source := ' using AWR '; -- If STATSPACK has been requested, check that it is installed and permissions granted. ELSE IF '&v_dodiagnostics' = 'nodiagnostics' THEN SELECT count(1) INTO cnt FROM all_tables WHERE owner ='PERFSTAT' AND table_name IN ('STATS$OSSTAT', 'STATS$OSSTATNAME', 'STATS$SNAPSHOT', 'STATS$SQL_SUMMARY', 'STATS$SYSSTAT', 'STATS$SYSTEM_EVENT', 'STATS$SYS_TIME_MODEL', 'STATS$TIME_MODEL_STATNAME'); - -- If we have access to STATSPACK, use STATSPACK as the source of performance metrics - IF cnt = 8 THEN + IF cnt = 8 THEN :sp := 'op_collect_statspack.sql'; l_tab_name := 'STATS$SNAPSHOT'; l_col_name := 'snap_time'; + :v_stats_source := ' using STATSPACK '; END IF; -- If instructed to not collect performance metrics, do not collect stats. ELSE IF '&v_dodiagnostics' = 'nostatspack' THEN :sp := 'prompt_nostatspack.sql'; + :v_stats_source := ' without performance data'; -- If we get here, then there was a problem. ELSE l_tab_name := 'ERROR - Unexpected parameter: &v_dodiagnostics'; END IF; END IF; END IF; + BEGIN IF l_tab_name = '---' THEN - dbms_output.put_line('No performance data will be collected.'); + dbms_output.put_line('No performance data will be collected.' || l_tab_name); ELSE - -- Verify there are metrics to collect. - BEGIN - EXECUTE IMMEDIATE 'SELECT count(1) FROM ' || upper(l_tab_name) || ' WHERE rownum < 2' INTO cnt ; + -- Verify there are metrics to collect. + BEGIN + EXECUTE IMMEDIATE 'SELECT count(1) FROM ' || upper(l_tab_name) || ' WHERE rownum < 2 AND dbid = &&v_statsDBID' INTO cnt ; + IF cnt = 0 THEN dbms_output.put_line('No data found in ' || upper(l_tab_name) || '. No performance data will be collected.'); + :v_stats_source := ' without performance data'; END IF; EXCEPTION WHEN table_does_not_exist THEN RAISE_APPLICATION_ERROR(-20002, 'This user does not have SELECT privileges on ' || upper(l_tab_name) || '. Please ensure the grants_wrapper.sql script has been executed for this user.'); @@ -457,32 +468,81 @@ BEGIN :minsnap := -1; :maxsnap := -1; :v_info_prompt := 'without performance data'; + :v_stats_source := ' without performance data'; ELSE :v_info_prompt := 'between snaps ' || :minsnap || ' and ' || :maxsnap; + :v_stats_source := :v_stats_source || 'between snaps ' || :minsnap || ' and ' || :maxsnap; END IF; ELSE - -- Get the snapshot range for STATSPACE stats. - THE_SQL := 'SELECT min(snap_time) , max(snap_time) FROM ' || l_tab_name || ' WHERE ' || l_col_name || ' >= (sysdate- &&dtrange ) AND dbid = :1 '; - EXECUTE IMMEDIATE the_sql INTO :minsnaptime, :maxsnaptime USING '&&v_dbid' ; + + -- Get the snapshot range for STATSPACK stats. + IF (length('&&v_statsStartDate') > 0 ) THEN -- IF user has specified a start date for the collection + THE_SQL := 'SELECT min(snap_time) , max(snap_time) FROM ' || l_tab_name || ' WHERE ' || l_col_name || ' BETWEEN to_date(:1, ''YYYYMMDD'') AND (to_date(:2, ''YYYYMMDD'') + &&dtrange ) AND dbid = :3 '; + EXECUTE IMMEDIATE the_sql INTO :minsnaptime, :maxsnaptime USING '&&v_statsStartDate','&&v_statsStartDate', NVL('&&v_statsDBID', '&&v_dbid') ; + ELSE -- Otherwise default to the last dtrange days + THE_SQL := 'SELECT min(snap_time) , max(snap_time) FROM ' || l_tab_name || ' WHERE ' || l_col_name || ' >= (sysdate - &&dtrange ) AND dbid = :1 '; + EXECUTE IMMEDIATE the_sql INTO :minsnaptime, :maxsnaptime USING NVL('&&v_statsDBID', '&&v_dbid') ; + END IF; IF :minsnaptime IS NULL THEN - dbms_output.put_line('Warning: No snapshots found within the last &&dtrange days. No performance data will be extracted.'); + dbms_output.put_line('Warning: No snapshots found within the requested &&dtrange days. No performance data will be extracted.'); :minsnaptime := sysdate; :maxsnaptime := sysdate; :v_info_prompt := 'without performance data'; - ELSE - :v_info_prompt := 'between ' || :minsnaptime || ' and ' || :maxsnaptime; + :v_stats_source := ' without performance data'; + -- Check there is more than one snapshot + ELSE IF (:minsnaptime = :maxsnaptime) THEN + dbms_output.put_line('Warning: Only one snapshot found within the requested &&dtrange days. No performance data will be extracted.'); + :minsnaptime := sysdate; + :maxsnaptime := sysdate; + :v_info_prompt := 'without performance data'; + :v_stats_source := ' without performance data'; + ELSE + -- Check that the snapshot window is greater than the collection window. + THE_SQL := 'SELECT min(snap_time) FROM ' || l_tab_name || ' WHERE dbid = :1 '; + EXECUTE IMMEDIATE THE_SQL INTO :firstsnaptime USING '&&v_dbid'; + IF (:minsnaptime > :firstsnaptime) THEN + :v_info_prompt := 'between times ' || :minsnaptime || ' and ' || :maxsnaptime; + :v_stats_source := :v_stats_source || 'between times ' || :minsnaptime || ' and ' || :maxsnaptime; + ELSE + -- If the very first snap available is within the collection range, use the next snap so we don't skew results. + THE_SQL := 'SELECT min(snap_time) FROM ' || l_tab_name || ' WHERE ' || l_col_name || ' > to_date(''' || :firstsnaptime || ''', ''YYYY-MM-DD HH24:MI:SS'') AND dbid = NVL(&&v_statsDBID, &&v_dbid) '; + + EXECUTE IMMEDIATE THE_SQL INTO :minsnaptime ; + -- Ensure the 'next' snap is not the max snap + IF (:minsnaptime = :maxsnaptime) THEN + dbms_output.put_line('Warning: Insufficient snapshots found within the requested &&dtrange days. No performance data will be extracted.'); + :minsnaptime := sysdate; + :maxsnaptime := sysdate; + :v_info_prompt := 'without performance data'; + :v_stats_source := ' without performance data'; + ELSE + :v_info_prompt := 'between times ' || :minsnaptime || ' and ' || :maxsnaptime; + :v_stats_source := 'between times ' || :minsnaptime || ' and ' || :maxsnaptime; + IF ( to_date(:maxsnaptime) - to_date(:minsnaptime) ) < 7 + THEN + :v_info_prompt := :v_info_prompt || ' less than 7 days of data, performance metrics may be skewed.'; + :v_stats_source := :v_stats_source || ' less than 7 days of data, performance metrics may be skewed.'; + END IF; + END IF; + END IF; + END IF; END IF; END IF; ELSE :v_info_prompt := 'without performance data'; + :v_stats_source := ' without performance data'; END IF; + :v_info_prompt := 'About to collect data for database &v_dbname ID &&v_dbid with stats id &&v_statsDBID ' || :v_info_prompt ; + :v_end_of_job_summary := 'Collected data for database &v_dbname ID &&v_dbid with stats id &&v_statsDBID ' || :v_stats_source ; END; / set termout off -SELECT NVL(:minsnap, -1) min_snapid, NVL(:maxsnap, -1) max_snapid, NVL(:minsnaptime, SYSDATE) min_snaptime, NVL(:maxsnaptime, SYSDATE) max_snaptime, :sp sp_script, :v_info_prompt info_prompt FROM dual; +SELECT NVL(:minsnap, -1) min_snapid, NVL(:maxsnap, -1) max_snapid, NVL(:minsnaptime, SYSDATE) min_snaptime, NVL(:maxsnaptime, SYSDATE) max_snaptime, + :sp sp_script, :v_info_prompt info_prompt, :v_end_of_job_summary end_of_job_summary +FROM dual; set termout on -PROMPT Collecting data for database &v_dbname '&&v_dbid' &p_info_prompt +PROMPT &p_info_prompt PROMPT set termout &TERMOUTOFF diff --git a/scripts/collector/oracle/sql/op_collect_nodiagnostics.sql b/scripts/collector/oracle/sql/op_collect_nodiagnostics.sql index ce2f42e4..d1c344ae 100644 --- a/scripts/collector/oracle/sql/op_collect_nodiagnostics.sql +++ b/scripts/collector/oracle/sql/op_collect_nodiagnostics.sql @@ -14,10 +14,7 @@ -- limitations under the License. -- set termout on -Prompt Skipping collection of statstics requiring the Oracle Diagnostics Pack license. -Prompt Will use STATSPACK data if available... +PROMPT Collecting performance data from STATSPACK set termout &TERMOUTOFF -PROMPT Running script &p_sp_script for STATSPACK - @&SQLDIR/&p_sp_script