diff --git a/Mortan/Rep_sql_monitor.sql b/Mortan/Rep_sql_monitor.sql new file mode 100644 index 0000000..f189765 --- /dev/null +++ b/Mortan/Rep_sql_monitor.sql @@ -0,0 +1,25 @@ +SET LONG 1000000 +SET LONGCHUNKSIZE 1000000 +SET LINESIZE 1000 +SET PAGESIZE 0 +SET TRIM ON +SET TRIMSPOOL ON +SET ECHO OFF +SET FEEDBACK OFF + +set termout on +accept psqlid prompt 'Enter the sql_id: ' + +define p_sql_id = '&psqlid' + +SPOOL D:\work\scripte\oracle\sql_monitor_reports\report_sql_monitor.htm + +SELECT DBMS_SQLTUNE.report_sql_monitor( + sql_id => '&p_sql_id', + type => 'HTML') AS report +FROM dual; + + +SPOOL OFF + + diff --git a/Mortan/awr_sqlid_perf_trend.sql b/Mortan/awr_sqlid_perf_trend.sql new file mode 100644 index 0000000..fcb1a5a --- /dev/null +++ b/Mortan/awr_sqlid_perf_trend.sql @@ -0,0 +1,51 @@ +-- Maris Elsins / Pythian / 2013 +-- SQL performance trends from AWR +-- Usage: @awr_sqlid_perf_trend.sql +-- i.e. @awr_sqlid_perf_trend.sql 46ah673phw02j 2 4 +-- i.e. The example above summarizes the execution statistics for sql_id 46ah673phw02j in last 2 days breaking down the statistics by 4 hours. +-- v1.0 - inital version +-- v1.1 - Adding instance_number to the outputs +set ver off pages 50000 lines 260 tab off +undef sql_id +undef days_history +undef interval_hours +def sql_id="&1" +def days_history="&2" +def interval_hours="&3" +col inst for 9999 +col time for a19 +col executions for 9999999999 +col rows_processed_1exec for 9999999.999 +col elapsed_time_s_1exec for 9999999.999 +col cpu_time_s_1exec for 9999999.999 +col iowait_s_1exec for 9999999.999 +col clwait_s_1exec for 9999999.999 +col apwait_s_1exec for 9999999.999 +col ccwait_s_1exec for 9999999.999 +col plsexec_time_s_1exec for 9999999.999 +col javexec_time_s_1exec for 9999999.999 +col buffer_gets_1exec for 999999999999.999 +col disk_reads_1exec for 999999999999.999 +col direct_writes_1exec for 999999999999.999 +BREAK ON inst SKIP 1 +select hss.instance_number inst, + to_char(trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24,'dd.mm.yyyy hh24:mi:ss') time, + sum(hss.executions_delta) executions, + round(sum(hss.elapsed_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) elapsed_time_s_1exec, + round(sum(hss.cpu_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) cpu_time_s_1exec, + round(sum(hss.iowait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) iowait_s_1exec, + round(sum(hss.clwait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) clwait_s_1exec, + round(sum(hss.apwait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) apwait_s_1exec, + round(sum(hss.ccwait_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) ccwait_s_1exec, + --round(sum(hss.plsexec_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) plsexec_time_s_1exec, + --round(sum(hss.javexec_time_delta)/1000000/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) javexec_time_s_1exec, + round(sum(hss.rows_processed_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) rows_processed_1exec, + round(sum(hss.buffer_gets_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) buffer_gets_1exec, + round(sum(hss.disk_reads_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) disk_reads_1exec, + round(sum(hss.direct_writes_delta)/decode(sum(hss.executions_delta),0,null,sum(hss.executions_delta)),3) direct_writes_1exec +from dba_hist_sqlstat hss, dba_hist_snapshot hs +where hss.sql_id='&sql_id' + and hss.snap_id=hs.snap_id + and hs.begin_interval_time>=trunc(sysdate)-&days_history+1 +group by hss.instance_number, trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24 +order by hss.instance_number,trunc(sysdate-&days_history+1)+trunc((cast(hs.begin_interval_time as date)-(trunc(sysdate-&days_history+1)))*24/(&interval_hours))*(&interval_hours)/24; diff --git a/Mortan/fsaj.sql b/Mortan/fsaj.sql new file mode 100644 index 0000000..de9449d --- /dev/null +++ b/Mortan/fsaj.sql @@ -0,0 +1,31 @@ +break on sql_id on child_number on plan_hash on execs on avg_etime on avg_lio on avg_rows on sql_text +col sql_text for a60 wrap +set verify off +set pagesize 999 +set lines 165 +col username format a13 +col prog format a22 +col sid format 999 +col child_number format 99999 heading CHILD +col ocategory format a10 +col avg_etime format 9,999,999.99 +col avg_pio format 9,999,999.99 +col avg_lio format 999,999,999 +col etime format 9,999,999.99 +col join for a20 + +select distinct s.sql_id, s.child_number, s.plan_hash_value plan_hash, executions execs, +(elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime, +buffer_gets/decode(nvl(executions,0),0,1,executions) avg_lio, +(rows_processed)/decode(nvl(executions,0),0,1,executions) avg_rows, +sql_text, +-- decode(options,'ANTI',operation||' '||options,null) join +case when options like '%ANTI%' then operation||' '||options end join +from v$sql s, v$sql_plan p +where s.sql_id = p.sql_id +and s.child_number = p.child_number +and upper(sql_text) like upper(nvl('&sql_text','%department%')) +and sql_text not like '%from v$sql where sql_text like nvl(%' +and s.sql_id like nvl('&sql_id',s.sql_id) +order by 1, 2, 3 +/ diff --git a/Mortan/fsp.sql b/Mortan/fsp.sql new file mode 100644 index 0000000..5388ac9 --- /dev/null +++ b/Mortan/fsp.sql @@ -0,0 +1,34 @@ +break on sql_id on child_number on plan_hash on execs on avg_etime on avg_lio on avg_rows on sql_text +col sql_text for a45 wrap +set verify off +set pagesize 999 +set lines 165 +col username format a13 +col prog format a22 +col sid format 999 +col child_number format 9999 heading CHILD +col ocategory format a10 +col avg_etime format 999.99 +col avg_rows format 999,999 +col avg_lio format 99,999 +col etime format 9,999,999.99 +col execs format 9999 +col join for a20 +-- col child_no noprint + +select distinct s.sql_id, s.child_number, s.plan_hash_value plan_hash, executions execs, +(elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime, + buffer_gets/decode(nvl(executions,0),0,1,executions) avg_lio, + (rows_processed)/decode(nvl(executions,0),0,1,executions) avg_rows, + sql_text, + -- decode(options,'SEMI',operation||' '||options,null) join + case when options like '%SEMI%' or options like '%ANTI%' then + operation||' '||options end join + from v$sql s, v$sql_plan p + where s.sql_id = p.sql_id + and s.child_number = p.child_number + and upper(sql_text) like upper(nvl('&sql_text','%department%')) + and sql_text not like '%from v$sql where sql_text like nvl(%' + and s.sql_id like nvl('&sql_id',s.sql_id) + order by 1, 2, 3 + / diff --git a/Mortan/fssj.sql b/Mortan/fssj.sql new file mode 100644 index 0000000..f4229e5 --- /dev/null +++ b/Mortan/fssj.sql @@ -0,0 +1,31 @@ +break on sql_id on child_number on plan_hash on execs on avg_etime on avg_lio on avg_rows on sql_text +col sql_text for a60 wrap +set verify off +set pagesize 999 +set lines 165 +col username format a13 +col prog format a22 +col sid format 999 +col child_number format 99999 heading CHILD +col ocategory format a10 +col avg_etime format 9,999,999.99 +col avg_pio format 9,999,999.99 +col avg_lio format 999,999,999 +col etime format 9,999,999.99 +col join for a20 + +select distinct s.sql_id, s.child_number, s.plan_hash_value plan_hash, executions execs, +(elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime, +buffer_gets/decode(nvl(executions,0),0,1,executions) avg_lio, +(rows_processed)/decode(nvl(executions,0),0,1,executions) avg_rows, +sql_text, +-- decode(options,'SEMI',operation||' '||options,null) join +case when options like '%SEMI%' then operation||' '||options end join +from v$sql s, v$sql_plan p +where s.sql_id = p.sql_id +and s.child_number = p.child_number +and upper(sql_text) like upper(nvl('&sql_text','%department%')) +and sql_text not like '%from v$sql where sql_text like nvl(%' +and s.sql_id like nvl('&sql_id',s.sql_id) +order by 1, 2, 3 +/ diff --git a/Mortan/one_sql_time_series.sql b/Mortan/one_sql_time_series.sql new file mode 100644 index 0000000..5a197e2 --- /dev/null +++ b/Mortan/one_sql_time_series.sql @@ -0,0 +1,73 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: one_sql_time_series.sql +-- +-- Purpose: Performance History for one SQL +-- +-- Author: Carlos Sierra +-- +-- Version: 2014/10/31 +-- +-- Usage: Script sql_performance_changed.sql lists SQL Statements with performance +-- improvement or regressed over some History. +-- This script one_sql_time_series.sql lists the Performance Time Series for +-- one SQL. +-- +-- Parameters: SQL_ID +-- +-- Example: @one_sql_time_series.sql +-- +-- Notes: Developed and tested on 11.2.0.3. +-- +-- Requires an Oracle Diagnostics Pack License since AWR data is accessed. +-- +-- To further investigate poorly performing SQL use sqltxplain.sql or sqlhc +-- (or planx.sql or sqlmon.sql or sqlash.sql). +-- +--------------------------------------------------------------------------------------- +-- +SPO one_sql_time_series.txt; +SET lin 200 ver OFF; + +COL instance_number FOR 9999 HEA 'Inst'; +COL end_time HEA 'End Time'; +COL plan_hash_value HEA 'Plan|Hash Value'; +COL executions_total FOR 999,999 HEA 'Execs|Total'; +COL rows_per_exec HEA 'Rows Per Exec'; +COL et_secs_per_exec HEA 'Elap Secs|Per Exec'; +COL cpu_secs_per_exec HEA 'CPU Secs|Per Exec'; +COL io_secs_per_exec HEA 'IO Secs|Per Exec'; +COL cl_secs_per_exec HEA 'Clus Secs|Per Exec'; +COL ap_secs_per_exec HEA 'App Secs|Per Exec'; +COL cc_secs_per_exec HEA 'Conc Secs|Per Exec'; +COL pl_secs_per_exec HEA 'PLSQL Secs|Per Exec'; +COL ja_secs_per_exec HEA 'Java Secs|Per Exec'; + +SELECT h.instance_number, + TO_CHAR(CAST(s.end_interval_time AS DATE), 'YYYY-MM-DD HH24:MI') end_time, + h.plan_hash_value, + h.executions_total, + TO_CHAR(ROUND(h.rows_processed_total / h.executions_total), '999,999,999,999') rows_per_exec, + TO_CHAR(ROUND(h.elapsed_time_total / h.executions_total / 1e6, 3), '999,990.000') et_secs_per_exec, + TO_CHAR(ROUND(h.cpu_time_total / h.executions_total / 1e6, 3), '999,990.000') cpu_secs_per_exec, + TO_CHAR(ROUND(h.iowait_total / h.executions_total / 1e6, 3), '999,990.000') io_secs_per_exec, + TO_CHAR(ROUND(h.clwait_total / h.executions_total / 1e6, 3), '999,990.000') cl_secs_per_exec, + TO_CHAR(ROUND(h.apwait_total / h.executions_total / 1e6, 3), '999,990.000') ap_secs_per_exec, + TO_CHAR(ROUND(h.ccwait_total / h.executions_total / 1e6, 3), '999,990.000') cc_secs_per_exec, + TO_CHAR(ROUND(h.plsexec_time_total / h.executions_total / 1e6, 3), '999,990.000') pl_secs_per_exec, + TO_CHAR(ROUND(h.javexec_time_total / h.executions_total / 1e6, 3), '999,990.000') ja_secs_per_exec + FROM dba_hist_sqlstat h, + dba_hist_snapshot s + WHERE h.sql_id = '&sql_id.' + AND h.executions_total > 0 + AND s.snap_id = h.snap_id + AND s.dbid = h.dbid + AND s.instance_number = h.instance_number + ORDER BY + h.sql_id, + h.instance_number, + s.end_interval_time, + h.plan_hash_value +/ + +SPO OFF; \ No newline at end of file diff --git a/Mortan/parms.sql b/Mortan/parms.sql new file mode 100644 index 0000000..ee7565b --- /dev/null +++ b/Mortan/parms.sql @@ -0,0 +1,44 @@ +me: parms.sql +-- Purpose: Display parameters and values. +- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for three values, all of which can be left blank. +-- +-- name: the name (or piece of a name) of the parameter(s) you wish to see +-- +-- isset: "TRUE" or "T" to see only nondefault parameters +-- +-- show_hidden: "Y" to show hidden parameters as well +-- +--------------------------------------------------------------------------------------- +set lines 155 +col name for a50 +col value for a70 +col isdefault for a8 +col ismodified for a10 +col isset for a10 +select name, value, isdefault, ismodified, isset +from +( +select flag,name,value,isdefault,ismodified, +case when isdefault||ismodified = 'TRUEFALSE' then 'FALSE' else 'TRUE' end isset +from + ( + select + decode(substr(i.ksppinm,1,1),'_',2,1) flag + , i.ksppinm name + , sv.ksppstvl value + , sv.ksppstdf isdefault +-- , decode(bitand(sv.ksppstvf,7),1,'MODIFIED',4,'SYSTEM_MOD','FALSE') ismodified + , decode(bitand(sv.ksppstvf,7),1,'TRUE',4,'TRUE','FALSE') ismodified + from x$ksppi i + , x$ksppsv sv + where i.indx = sv.indx + ) +) +where name like nvl('%¶meter%',name) +and upper(isset) like upper(nvl('%&isset%',isset)) +and flag not in (decode('&show_hidden','Y',3,2)) +order by flag,replace(name,'_','') +/ diff --git a/Mortan/sql_performance_changed.sql b/Mortan/sql_performance_changed.sql new file mode 100644 index 0000000..e2294b2 --- /dev/null +++ b/Mortan/sql_performance_changed.sql @@ -0,0 +1,131 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: sql_performance_changed.sql +-- +-- Purpose: Lists SQL Statements with Elapsed Time per Execution changing over time +-- +-- Author: Carlos Sierra +-- +-- Version: 2014/10/31 +-- +-- Usage: Lists statements that have changed their elapsed time per execution over +-- some history. +-- Uses the ration between "elapsed time per execution" and the median of +-- this metric for SQL statements within the sampled history, and using +-- linear regression identifies those that have changed the most. In other +-- words where the slope of the linear regression is larger. Positive slopes +-- are considered "improving" while negative are "regressing". +-- +-- Example: @sql_performance_changed.sql +-- +-- Notes: Developed and tested on 11.2.0.3. +-- +-- Requires an Oracle Diagnostics Pack License since AWR data is accessed. +-- +-- To further investigate poorly performing SQL use sqltxplain.sql or sqlhc +-- (or planx.sql or sqlmon.sql or sqlash.sql). +-- +--------------------------------------------------------------------------------------- +-- +SPO sql_performance_changed.txt; +DEF days_of_history_accessed = '31'; +DEF captured_at_least_x_times = '10'; +DEF captured_at_least_x_days_apart = '5'; +DEF med_elap_microsecs_threshold = '1e4'; +DEF min_slope_threshold = '0.1'; +DEF max_num_rows = '20'; + +SET lin 200 ver OFF; +COL row_n FOR A2 HEA '#'; +COL med_secs_per_exec HEA 'Median Secs|Per Exec'; +COL std_secs_per_exec HEA 'Std Dev Secs|Per Exec'; +COL avg_secs_per_exec HEA 'Avg Secs|Per Exec'; +COL min_secs_per_exec HEA 'Min Secs|Per Exec'; +COL max_secs_per_exec HEA 'Max Secs|Per Exec'; +COL plans FOR 9999; +COL sql_text_80 FOR A80; + +PRO SQL Statements with "Elapsed Time per Execution" changing over time + +WITH +per_time AS ( +SELECT h.dbid, + h.sql_id, + SYSDATE - CAST(s.end_interval_time AS DATE) days_ago, + SUM(h.elapsed_time_total) / SUM(h.executions_total) time_per_exec + FROM dba_hist_sqlstat h, + dba_hist_snapshot s + WHERE h.executions_total > 0 + AND s.snap_id = h.snap_id + AND s.dbid = h.dbid + AND s.instance_number = h.instance_number + AND CAST(s.end_interval_time AS DATE) > SYSDATE - &&days_of_history_accessed. + GROUP BY + h.dbid, + h.sql_id, + SYSDATE - CAST(s.end_interval_time AS DATE) +), +avg_time AS ( +SELECT dbid, + sql_id, + MEDIAN(time_per_exec) med_time_per_exec, + STDDEV(time_per_exec) std_time_per_exec, + AVG(time_per_exec) avg_time_per_exec, + MIN(time_per_exec) min_time_per_exec, + MAX(time_per_exec) max_time_per_exec + FROM per_time + GROUP BY + dbid, + sql_id +HAVING COUNT(*) >= &&captured_at_least_x_times. + AND MAX(days_ago) - MIN(days_ago) >= &&captured_at_least_x_days_apart. + AND MEDIAN(time_per_exec) > &&med_elap_microsecs_threshold. +), +time_over_median AS ( +SELECT h.dbid, + h.sql_id, + h.days_ago, + (h.time_per_exec / a.med_time_per_exec) time_per_exec_over_med, + a.med_time_per_exec, + a.std_time_per_exec, + a.avg_time_per_exec, + a.min_time_per_exec, + a.max_time_per_exec + FROM per_time h, avg_time a + WHERE a.sql_id = h.sql_id +), +ranked AS ( +SELECT RANK () OVER (ORDER BY ABS(REGR_SLOPE(t.time_per_exec_over_med, t.days_ago)) DESC) rank_num, + t.dbid, + t.sql_id, + CASE WHEN REGR_SLOPE(t.time_per_exec_over_med, t.days_ago) > 0 THEN 'IMPROVING' ELSE 'REGRESSING' END change, + ROUND(REGR_SLOPE(t.time_per_exec_over_med, t.days_ago), 3) slope, + ROUND(AVG(t.med_time_per_exec)/1e6, 3) med_secs_per_exec, + ROUND(AVG(t.std_time_per_exec)/1e6, 3) std_secs_per_exec, + ROUND(AVG(t.avg_time_per_exec)/1e6, 3) avg_secs_per_exec, + ROUND(MIN(t.min_time_per_exec)/1e6, 3) min_secs_per_exec, + ROUND(MAX(t.max_time_per_exec)/1e6, 3) max_secs_per_exec + FROM time_over_median t + GROUP BY + t.dbid, + t.sql_id +HAVING ABS(REGR_SLOPE(t.time_per_exec_over_med, t.days_ago)) > &&min_slope_threshold. +) +SELECT LPAD(ROWNUM, 2) row_n, + r.sql_id, + r.change, + TO_CHAR(r.slope, '990.000MI') slope, + TO_CHAR(r.med_secs_per_exec, '999,990.000') med_secs_per_exec, + TO_CHAR(r.std_secs_per_exec, '999,990.000') std_secs_per_exec, + TO_CHAR(r.avg_secs_per_exec, '999,990.000') avg_secs_per_exec, + TO_CHAR(r.min_secs_per_exec, '999,990.000') min_secs_per_exec, + TO_CHAR(r.max_secs_per_exec, '999,990.000') max_secs_per_exec, + (SELECT COUNT(DISTINCT p.plan_hash_value) FROM dba_hist_sql_plan p WHERE p.dbid = r.dbid AND p.sql_id = r.sql_id) plans, + REPLACE((SELECT DBMS_LOB.SUBSTR(s.sql_text, 80) FROM dba_hist_sqltext s WHERE s.dbid = r.dbid AND s.sql_id = r.sql_id), CHR(10)) sql_text_80 + FROM ranked r + WHERE r.rank_num <= &&max_num_rows. + ORDER BY + r.rank_num +/ + +SPO OFF; \ No newline at end of file diff --git a/Mortan/valid_parms.sql b/Mortan/valid_parms.sql new file mode 100644 index 0000000..4f620f6 --- /dev/null +++ b/Mortan/valid_parms.sql @@ -0,0 +1,37 @@ +-------------------------------------------------------------------------------- +-- +-- File name: pvalid.sql +-- Purpose: Show valid parameter values from V$PARAMETER_VALID_VALUES +-- underlying X$ table X$KSPVLD_VALUES +-- +-- Author: Tanel Poder +-- Copyright: (c) http://www.tanelpoder.com +-- +-- Modified by Kerry Osborne to prompt for value instead of using coommand line parameter. +-- +-------------------------------------------------------------------------------- + +set lines 155 +COL pvalid_default HEAD DEFAULT FOR A7 +COL pvalid_value HEAD VALUE FOR A30 +COL pvalid_name HEAD PARAMETER FOR A50 +COL pvalid_par# HEAD PAR# FOR 99999 + +BREAK ON pvalid_par# skip 1 + +SELECT +-- INST_ID, + PARNO_KSPVLD_VALUES pvalid_par#, + NAME_KSPVLD_VALUES pvalid_name, +-- ORDINAL_KSPVLD_VALUES, + VALUE_KSPVLD_VALUES pvalid_value, + DECODE(ISDEFAULT_KSPVLD_VALUES, 'FALSE', '', 'DEFAULT' ) pvalid_default +FROM + X$KSPVLD_VALUES +WHERE + LOWER(NAME_KSPVLD_VALUES) LIKE '%'||LOWER(nvl('&pname',name_kspvld_values))||'%' +ORDER BY + pvalid_par#, + pvalid_default, + pvalid_Value +/