From e9ee5a91a3e98d9b372269fa57c31d87c29389f8 Mon Sep 17 00:00:00 2001 From: Franz Rustler Date: Fri, 28 Nov 2014 14:34:09 +0100 Subject: [PATCH] create plan, outline, profile scripts --- Mortan/as.sql | 19 ++++ Mortan/awr_plan_change.sql | 21 +++++ Mortan/awr_plan_stats.sql | 41 +++++++++ Mortan/baseline_hints.sql | 15 ++++ Mortan/baselines.sql | 19 ++++ Mortan/col_stats.sql | 20 +++++ Mortan/create_baseline.sql | 12 +++ Mortan/create_baseline_awr.sql | 131 +++++++++++++++++++++++++++ Mortan/create_outline.sql | 58 ++++++++++++ Mortan/create_sql_profile.sql | 116 ++++++++++++++++++++++++ Mortan/create_sql_profile_awr.sql | 115 ++++++++++++++++++++++++ Mortan/display_raw.sql | 34 +++++++ Mortan/dplan.sql | 4 + Mortan/dplan_alias.sql | 3 + Mortan/dplan_awr.sql | 2 + Mortan/find_sql.sql | 24 +++++ Mortan/find_sql_awr.sql | 52 +++++++++++ Mortan/find_sql_using_baseline.sql | 26 ++++++ Mortan/find_sql_using_outline.sql | 25 ++++++ Mortan/find_sql_using_profile.sql | 27 ++++++ Mortan/move_sql_profile.sql | 138 +++++++++++++++++++++++++++++ Mortan/optim_parms.sql | 23 +++++ Mortan/outline_hints.sql | 4 + Mortan/outlines.sql | 22 +++++ Mortan/pln.sql | 22 ++--- Mortan/restore_table_stats.sql | 7 ++ Mortan/set_col_stats.sql | 28 ++++++ Mortan/sql_hints.sql | 15 ++++ Mortan/sql_profile_hints.sql | 84 ++++++++++++++++++ Mortan/sql_profiles.sql | 9 ++ Mortan/unstable_plans.sql | 54 +++++++++++ Mortan/whats_changed.sql | 122 +++++++++++++++++++++++++ 32 files changed, 1281 insertions(+), 11 deletions(-) create mode 100644 Mortan/as.sql create mode 100644 Mortan/awr_plan_change.sql create mode 100644 Mortan/awr_plan_stats.sql create mode 100644 Mortan/baseline_hints.sql create mode 100644 Mortan/baselines.sql create mode 100644 Mortan/col_stats.sql create mode 100644 Mortan/create_baseline.sql create mode 100644 Mortan/create_baseline_awr.sql create mode 100644 Mortan/create_outline.sql create mode 100644 Mortan/create_sql_profile.sql create mode 100644 Mortan/create_sql_profile_awr.sql create mode 100644 Mortan/display_raw.sql create mode 100644 Mortan/dplan.sql create mode 100644 Mortan/dplan_alias.sql create mode 100644 Mortan/dplan_awr.sql create mode 100644 Mortan/find_sql.sql create mode 100644 Mortan/find_sql_awr.sql create mode 100644 Mortan/find_sql_using_baseline.sql create mode 100644 Mortan/find_sql_using_outline.sql create mode 100644 Mortan/find_sql_using_profile.sql create mode 100644 Mortan/move_sql_profile.sql create mode 100644 Mortan/optim_parms.sql create mode 100644 Mortan/outline_hints.sql create mode 100644 Mortan/outlines.sql create mode 100644 Mortan/restore_table_stats.sql create mode 100644 Mortan/set_col_stats.sql create mode 100644 Mortan/sql_hints.sql create mode 100644 Mortan/sql_profile_hints.sql create mode 100644 Mortan/sql_profiles.sql create mode 100644 Mortan/unstable_plans.sql create mode 100644 Mortan/whats_changed.sql diff --git a/Mortan/as.sql b/Mortan/as.sql new file mode 100644 index 0000000..ac9f81a --- /dev/null +++ b/Mortan/as.sql @@ -0,0 +1,19 @@ +set pagesize 999 +set lines 150 +col username format a13 +col prog format a10 trunc +col sql_text format a41 trunc +col sid format 999 +col child for 99999 +col avg_etime for 999,999.99 +select sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child, plan_hash_value, executions execs, +(elapsed_time/decode(nvl(executions,0),0,1,executions))/1000000 avg_etime, +sql_text +from v$session a, v$sql b +where status = 'ACTIVE' +and username is not null +and a.sql_id = b.sql_id +and a.sql_child_number = b.child_number +and sql_text not like 'select sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child,%' -- don't show this query +order by sql_id, sql_child_number +/ diff --git a/Mortan/awr_plan_change.sql b/Mortan/awr_plan_change.sql new file mode 100644 index 0000000..c897c24 --- /dev/null +++ b/Mortan/awr_plan_change.sql @@ -0,0 +1,21 @@ +set lines 155 +col execs for 999,999,999 +col avg_etime for 999,999.999 +col avg_lio for 999,999,999.9 +col begin_interval_time for a30 +col node for 99999 +break on plan_hash_value on startup_time skip 1 +select ss.snap_id, ss.instance_number node, begin_interval_time, sql_id, plan_hash_value, +nvl(executions_delta,0) execs, +(elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime, +(buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio, +(disk_reads_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_pio +from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS +where sql_id = nvl('&sql_id','4dqs2k5tynk61') +and ss.snap_id = S.snap_id +and ss.instance_number = S.instance_number +and s.instance_number like nvl('&instance_number',s.instance_number) +and executions_delta > 0 +order by 1, 2, 3 +/ + diff --git a/Mortan/awr_plan_stats.sql b/Mortan/awr_plan_stats.sql new file mode 100644 index 0000000..e5c7de6 --- /dev/null +++ b/Mortan/awr_plan_stats.sql @@ -0,0 +1,41 @@ +-- Note that I have modified this script slightly to include snaps with 0 executions. +-- This is to account for situations with very long running statements (that generally +-- cross snapshot boundaries). In these situations, the executions_delta is incremented +-- in the snapshot when the statement begins. There will be 0 executions_delta in +-- subsequent snapshots, but the time and lio's should still be considered. +set lines 155 +col execs for 999,999,999 +col etime for 999,999,999.9 +col avg_etime for 999,999.999 +col avg_cpu_time for 999,999.999 +col avg_lio for 999,999,999.9 +col avg_pio for 9,999,999.9 +col begin_interval_time for a30 +col node for 99999 +break on plan_hash_value on startup_time skip 1 +select sql_id, plan_hash_value, +sum(execs) execs, +-- sum(etime) etime, +sum(etime)/sum(execs) avg_etime, +sum(cpu_time)/sum(execs) avg_cpu_time, +sum(lio)/sum(execs) avg_lio, +sum(pio)/sum(execs) avg_pio +from ( +select ss.snap_id, ss.instance_number node, begin_interval_time, sql_id, plan_hash_value, +nvl(executions_delta,0) execs, +elapsed_time_delta/1000000 etime, +(elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime, +buffer_gets_delta lio, +disk_reads_delta pio, +cpu_time_delta/1000000 cpu_time, +(buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio, +(cpu_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta)) avg_cpu_time +from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS +where sql_id = nvl('&sql_id','4dqs2k5tynk61') +and ss.snap_id = S.snap_id +and ss.instance_number = S.instance_number +-- and executions_delta > 0 +) +group by sql_id, plan_hash_value +order by 5 +/ diff --git a/Mortan/baseline_hints.sql b/Mortan/baseline_hints.sql new file mode 100644 index 0000000..40c16e9 --- /dev/null +++ b/Mortan/baseline_hints.sql @@ -0,0 +1,15 @@ +select +extractvalue(value(d), '/hint') as outline_hints +from +xmltable('/outline_data/hint' +passing ( +select +xmltype(comp_data) as xmlval +from +sqlobj$data sod, sqlobj$ so +where so.signature = sod.signature +and so.plan_id = sod.plan_id +and comp_data is not null +and name like '&baseline_plan_name' +) +) d; diff --git a/Mortan/baselines.sql b/Mortan/baselines.sql new file mode 100644 index 0000000..beb7766 --- /dev/null +++ b/Mortan/baselines.sql @@ -0,0 +1,19 @@ +set lines 155 +col sql_text for a35 trunc +col last_executed for a28 +col enabled for a7 +col plan_hash_value for a16 +col last_executed for a16 +select spb.sql_handle, spb.plan_name, to_char(so.plan_id) plan_hash_value, +dbms_lob.substr(sql_text,3999,1) sql_text, +spb.enabled, spb.accepted, spb.fixed, +to_char(spb.last_executed,'dd-mon-yy HH24:MI') last_executed +from +dba_sql_plan_baselines spb, sqlobj$ so +where spb.signature = so.signature +and spb.plan_name = so.name +and dbms_lob.substr(sql_text,3999,1) like nvl('&sql_text', dbms_lob.substr(sql_text,3999,1)) +-- spb.sql_text like nvl('%'||'&sql_text'||'%',spb.sql_text) +and spb.sql_handle like nvl('&name',spb.sql_handle) +and spb.plan_name like nvl('&plan_name',spb.plan_name) +/ diff --git a/Mortan/col_stats.sql b/Mortan/col_stats.sql new file mode 100644 index 0000000..ad5b5c6 --- /dev/null +++ b/Mortan/col_stats.sql @@ -0,0 +1,20 @@ +set verify off +set pagesize 999 +set lines 165 +col table_name format a25 trunc +col column_name format a25 +col avg_len format 9999999 +col NDV format 999,999,999 +col buckets format 999999 +col low_value format a15 +col high_value format a15 +col density for .999999999 +col data_type for a10 +select column_name, data_type, avg_col_len, density, num_distinct NDV, histogram, num_buckets buckets, sample_size, last_analyzed, +display_raw(low_value,data_type) low_value, display_raw(high_value,data_type) high_value +from dba_tab_cols +where owner like nvl('&owner',owner) +and table_name like nvl('&table_name',table_name) +and column_name like nvl('%&column_name%',column_name) +order by internal_column_id +/ diff --git a/Mortan/create_baseline.sql b/Mortan/create_baseline.sql new file mode 100644 index 0000000..f31136f --- /dev/null +++ b/Mortan/create_baseline.sql @@ -0,0 +1,12 @@ +/* +exec :ret := dbms_spm.load_plans_from_cursor_cache(- + sql_id=>'&v_sql_id', - + plan_hash_value=>&v_plan_hash_value, - +*/ +var ret number +exec :ret := dbms_spm.load_plans_from_cursor_cache(- + sql_id=>'&sql_id', - + plan_hash_value=>&plan_hash_value,- + fixed=>'&fixed'); + + diff --git a/Mortan/create_baseline_awr.sql b/Mortan/create_baseline_awr.sql new file mode 100644 index 0000000..a7b9d18 --- /dev/null +++ b/Mortan/create_baseline_awr.sql @@ -0,0 +1,131 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: create_baseline_awr.sql +-- +-- Purpose: Creates a SQL Baseline on a SQL statement using a plan in AWR. +- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for five values. +-- +-- sql_id: the sql_id of the statement (must be in the shared pool) +-- +-- plan_hash_value: the hash value of the plan +-- +-- fixed: a toggle to turn on or off the fixed feature (NO) +-- +-- enabled: a toggle to turn on or off the enabled flag (YES) +-- +-- plan_name: the name of the plan (SQLID_sqlid_planhashvalue) +-- +-- Description: This script uses the DBMS_SPM.LOAD_PLANS_FROM_SQLSET procedure to +-- create a Baseline on a statement that is currently in the shared pool. +-- The plan will be pulled from the AWR tables. By default, the Baseline +-- is renamed to include the sql_id and plan_hash_value. +-- +-- See kerryosborne.oracle-guy.com for additional information. +----------------------------------------------------------------------------------------- +set serveroutput on +set sqlblanklines on +set feedback off +col sql_text for a50 trunc +col last_executed for a28 +col enabled for a7 +col plan_hash_value for a16 +col last_executed for a16 +col sql_handle for a24 +accept sql_id - + prompt 'Enter value for SQL_ID: ' - + default '3ggjbbd2varq2' +accept plan_hash_value - + prompt 'Enter value for PLAN_HASH_VALUE: ' - + default '568322376' +accept fixed - + prompt 'Enter value for fixed (NO): ' - + default 'NO' +accept enabled - + prompt 'Enter value for enabled (YES): ' - + default 'YES' +accept plan_name - + prompt 'Enter value for plan_name (ID_sqlid_planhashvalue): ' - + default 'X0X0X0X0' + +exec DBMS_SQLTUNE.CREATE_SQLSET('CREATE_BASELINE_AWR'); + +declare +baseline_ref_cursor DBMS_SQLTUNE.SQLSET_CURSOR; +min_snap number; +max_snap number; +ret binary_integer; +l_sql_handle varchar2(40); +l_plan_name varchar2(40); +l_old_plan_name varchar2(40); +major_release varchar2(3); +minor_release varchar2(3); +BEGIN +select regexp_replace(version,'\..*'), regexp_substr(version,'[0-9]+',1,2) into major_release, minor_release from v$instance; + +select min(snap_id), max(snap_id) into min_snap, max_snap from dba_hist_snapshot; + +open baseline_ref_cursor for +select VALUE(p) from table(DBMS_SQLTUNE.SELECT_WORKLOAD_REPOSITORY(min_snap, max_snap, +'sql_id='||CHR(39)||'&&sql_id'||CHR(39)||' and plan_hash_value=&plan_hash_value',NULL,NULL,NULL,NULL,NULL,NULL,'ALL')) p; + +DBMS_SQLTUNE.LOAD_SQLSET('CREATE_BASELINE_AWR', baseline_ref_cursor); + +ret := DBMS_SPM.LOAD_PLANS_FROM_SQLSET ( +sqlset_name => 'CREATE_BASELINE_AWR', +sqlset_owner => 'SYS', +fixed => 'NO', +enabled => 'YES'); + +if minor_release = '1' then + +-- 11gR1 has a bug that prevents renaming Baselines + + select plan_name + into l_plan_name + from dba_sql_plan_baselines spb + where created > sysdate-(1/24/60/15); + +else + +-- This statements looks for Baselines create in the last 4 seconds + + select sql_handle, plan_name, + decode('&&plan_name','X0X0X0X0','SQLID_'||'&&sql_id'||'_'||'&&plan_hash_value','&&plan_name') + into l_sql_handle, l_old_plan_name, l_plan_name + from dba_sql_plan_baselines spb + where created > sysdate-(1/24/60/15); + + + ret := dbms_spm.alter_sql_plan_baseline( + sql_handle=>l_sql_handle, + plan_name=>l_old_plan_name, + attribute_name=>'PLAN_NAME', + attribute_value=>l_plan_name); + +end if; + +dbms_output.put_line(' '); +dbms_output.put_line('Baseline '||upper(l_plan_name)||' created.'); +dbms_output.put_line(' '); + +end; +/ +/* +set feedback on +select NAME,OWNER,CREATED,STATEMENT_COUNT FROM DBA_SQLSET where name like 'CREATE_BASELINE_AWR'; +select spb.sql_handle, spb.plan_name, spb.sql_text, +spb.enabled, spb.accepted, spb.fixed, +to_char(spb.last_executed,'dd-mon-yy HH24:MI') last_executed +from dba_sql_plan_baselines spb +where upper(spb.plan_name) = upper('&&plan_name'); +*/ +clear breaks +exec DBMS_SQLTUNE.DROP_SQLSET( sqlset_name => 'CREATE_BASELINE_AWR' ); +undef sql_id +undef plan_hash_value +undef fixed +undef enabled +undef plan_name diff --git a/Mortan/create_outline.sql b/Mortan/create_outline.sql new file mode 100644 index 0000000..cb2b016 --- /dev/null +++ b/Mortan/create_outline.sql @@ -0,0 +1,58 @@ +-- Kerry Osborne +-- +-- this is here to attempt to avoid the "ORA-03113: end-of-file on communication channel" error +-- (per metalink) to workaround Bug 5454975 fixed 10.2.0.4 +alter session set use_stored_outlines=true; + +set serveroutput on +set pagesize 9999 +set linesize 155 +var hval number +accept sql_id - + prompt 'Enter value for sql_id: ' +accept child_number - + prompt 'Enter value for child_number: ' +accept o_name - + prompt 'Enter value for outline_name (OL_sqlid_planhash): ' - + default 'X0X0X0X0' +accept category - + prompt 'Enter value for category (DEFAULT): ' - + default 'DEFAULT' + +DECLARE +-- oname varchar2(30) := 'XOXOXOXO'; +l_name varchar2(30); +sql_string varchar2(300); +BEGIN + +select +hash_value, +decode('&&o_name','X0X0X0X0','OL_&&sql_id'||'_'||plan_hash_value,'&&o_name') +into +:hval, l_name +from +v$sql +where +sql_id = '&&sql_id' +and child_number = &&child_number; + + DBMS_OUTLN.create_outline( + hash_value => :hval, + child_number => &&child_number, + category => '&&category'); + + select 'alter outline '||name||' rename to "'||l_name||'"' into sql_string + from dba_outlines + where timestamp = (select max(timestamp) from dba_outlines); + dbms_output.put_line(' '); + +execute immediate sql_string; +dbms_outln.clear_used('&&o_name'); +dbms_output.put_line('Outline '||l_name||' created.'); + +END; +/ +undef sql_id +undef child_number +undef o_name +undef category diff --git a/Mortan/create_sql_profile.sql b/Mortan/create_sql_profile.sql new file mode 100644 index 0000000..1cd02d7 --- /dev/null +++ b/Mortan/create_sql_profile.sql @@ -0,0 +1,116 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: create_sql_profile.sql +-- +-- Purpose: Create SQL Profile based on Outline hints in V$SQL.OTHER_XML. +-- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for four values. +-- +-- sql_id: the sql_id of the statement to attach the profile to (must be in the shared pool) +-- +-- child_no: the child_no of the statement from v$sql +-- +-- profile_name: the name of the profile to be generated +-- +-- category: the name of the category for the profile +-- +-- force_macthing: a toggle to turn on or off the force_matching feature +-- +-- Description: +-- +-- Based on a script by Randolf Giest. +-- +-- Mods: This is the 2nd version of this script which removes dependency on rg_sqlprof1.sql. +-- +-- See kerryosborne.oracle-guy.com for additional information. +--------------------------------------------------------------------------------------- +-- + +-- @rg_sqlprof1 '&&sql_id' &&child_no '&&category' '&force_matching' + +set feedback off +set sqlblanklines on + +accept sql_id - + prompt 'Enter value for sql_id: ' - + default 'X0X0X0X0' +accept child_no - + prompt 'Enter value for child_no (0): ' - + default '0' +accept profile_name - + prompt 'Enter value for profile_name (PROF_sqlid_planhash): ' - + default 'X0X0X0X0' +accept category - + prompt 'Enter value for category (DEFAULT): ' - + default 'DEFAULT' +accept force_matching - + prompt 'Enter value for force_matching (FALSE): ' - + default 'false' + +declare +ar_profile_hints sys.sqlprof_attr; +cl_sql_text clob; +l_profile_name varchar2(30); +begin +select +extractvalue(value(d), '/hint') as outline_hints +bulk collect +into +ar_profile_hints +from +xmltable('/*/outline_data/hint' +passing ( +select +xmltype(other_xml) as xmlval +from +v$sql_plan +where +sql_id = '&&sql_id' +and child_number = &&child_no +and other_xml is not null +) +) d; + +select +sql_fulltext, +decode('&&profile_name','X0X0X0X0','PROF_&&sql_id'||'_'||plan_hash_value,'&&profile_name') +into +cl_sql_text, l_profile_name +from +v$sql +where +sql_id = '&&sql_id' +and child_number = &&child_no; + +dbms_sqltune.import_sql_profile( +sql_text => cl_sql_text, +profile => ar_profile_hints, +category => '&&category', +name => l_profile_name, +force_match => &&force_matching +-- replace => true +); + + dbms_output.put_line(' '); + dbms_output.put_line('SQL Profile '||l_profile_name||' created.'); + dbms_output.put_line(' '); + +exception +when NO_DATA_FOUND then + dbms_output.put_line(' '); + dbms_output.put_line('ERROR: sql_id: '||'&&sql_id'||' Child: '||'&&child_no'||' not found in v$sql.'); + dbms_output.put_line(' '); + +end; +/ + +undef sql_id +undef child_no +undef profile_name +undef category +undef force_matching + +set sqlblanklines off +set feedback on diff --git a/Mortan/create_sql_profile_awr.sql b/Mortan/create_sql_profile_awr.sql new file mode 100644 index 0000000..0cc3074 --- /dev/null +++ b/Mortan/create_sql_profile_awr.sql @@ -0,0 +1,115 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: create_sql_profile_awr.sql +-- +-- Purpose: Create SQL Profile based on Outline hints in V$SQL.OTHER_XML. +-- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for five values. +-- +-- sql_id: the sql_id of the statement to attach the profile to +-- (must be in the shared pool and in AWR history) +-- +-- plan_hash_value: the plan_hash_value of the statement in AWR history +-- +-- profile_name: the name of the profile to be generated +-- +-- category: the name of the category for the profile +-- +-- force_macthing: a toggle to turn on or off the force_matching feature +-- +-- Description: +-- +-- Based on a script by Randolf Giest. +-- +-- Mods: This is the 2nd version of this script which removes dependency on rg_sqlprof2.sql. +-- +-- See kerryosborne.oracle-guy.com for additional information. +--------------------------------------------------------------------------------------- +-- + +-- @rg_sqlprof1 '&&sql_id' &&child_no '&&category' '&force_matching' + +set feedback off +set sqlblanklines on + +accept sql_id - + prompt 'Enter value for sql_id: ' - + default 'X0X0X0X0' +accept plan_hash_value - + prompt 'Enter value for plan_hash_value: ' +accept profile_name - + prompt 'Enter value for profile_name (PROF_sqlid_planhash): ' - + default 'X0X0X0X0' +accept category - + prompt 'Enter value for category (DEFAULT): ' - + default 'DEFAULT' +accept force_matching - + prompt 'Enter value for force_matching (FALSE): ' - + default 'false' + +declare +ar_profile_hints sys.sqlprof_attr; +cl_sql_text clob; +l_profile_name varchar2(30); +begin +select +extractvalue(value(d), '/hint') as outline_hints +bulk collect +into +ar_profile_hints +from +xmltable('/*/outline_data/hint' +passing ( +select +xmltype(other_xml) as xmlval +from +dba_hist_sql_plan +where +sql_id = '&&sql_id' +and plan_hash_value = &&plan_hash_value +and other_xml is not null +) +) d; + +select +sql_text, +decode('&&profile_name','X0X0X0X0','PROF_&&sql_id'||'_'||'&&plan_hash_value','&&profile_name') +into +cl_sql_text, l_profile_name +from +dba_hist_sqltext +where +sql_id = '&&sql_id'; + +dbms_sqltune.import_sql_profile( +sql_text => cl_sql_text, +profile => ar_profile_hints, +category => '&&category', +name => l_profile_name, +force_match => &&force_matching +-- replace => true +); + + dbms_output.put_line(' '); + dbms_output.put_line('SQL Profile '||l_profile_name||' created.'); + dbms_output.put_line(' '); + +exception +when NO_DATA_FOUND then + dbms_output.put_line(' '); + dbms_output.put_line('ERROR: sql_id: '||'&&sql_id'||' Plan: '||'&&plan_hash_value'||' not found in AWR.'); + dbms_output.put_line(' '); + +end; +/ + +undef sql_id +undef plan_hash_value +undef profile_name +undef category +undef force_matching + +set sqlblanklines off +set feedback on diff --git a/Mortan/display_raw.sql b/Mortan/display_raw.sql new file mode 100644 index 0000000..f540ac8 --- /dev/null +++ b/Mortan/display_raw.sql @@ -0,0 +1,34 @@ +create or replace function display_raw (rawval raw, type varchar2) +return varchar2 +is + cn number; + cv varchar2(32); + cd date; + cnv nvarchar2(32); + cr rowid; + cc char(32); +begin + if (type = 'NUMBER') then + dbms_stats.convert_raw_value(rawval, cn); + return to_char(cn); + elsif (type = 'VARCHAR2') then + dbms_stats.convert_raw_value(rawval, cv); + return to_char(cv); + elsif (type = 'DATE') then + dbms_stats.convert_raw_value(rawval, cd); + return to_char(cd); + elsif (type = 'NVARCHAR2') then + dbms_stats.convert_raw_value(rawval, cnv); + return to_char(cnv); + elsif (type = 'ROWID') then + dbms_stats.convert_raw_value(rawval, cr); + return to_char(cnv); + elsif (type = 'CHAR') then + dbms_stats.convert_raw_value(rawval, cc); + return to_char(cc); + else + return 'UNKNOWN DATATYPE'; + end if; +end; +/ + diff --git a/Mortan/dplan.sql b/Mortan/dplan.sql new file mode 100644 index 0000000..61b5318 --- /dev/null +++ b/Mortan/dplan.sql @@ -0,0 +1,4 @@ +set lines 150 +select * from table(dbms_xplan.display_cursor('&sql_id','&child_no','typical')) +/ + diff --git a/Mortan/dplan_alias.sql b/Mortan/dplan_alias.sql new file mode 100644 index 0000000..ba6c97f --- /dev/null +++ b/Mortan/dplan_alias.sql @@ -0,0 +1,3 @@ +set lines 150 +select * from table(dbms_xplan.display_cursor('&sql_id','&child_no','alias')) +/ diff --git a/Mortan/dplan_awr.sql b/Mortan/dplan_awr.sql new file mode 100644 index 0000000..e752b65 --- /dev/null +++ b/Mortan/dplan_awr.sql @@ -0,0 +1,2 @@ +SELECT * FROM table(dbms_xplan.display_awr(nvl('&sql_id','a96b61z6vp3un'),nvl('&plan_hash_value',null),null,'typical +peeked_binds')) +/ diff --git a/Mortan/find_sql.sql b/Mortan/find_sql.sql new file mode 100644 index 0000000..4519a98 --- /dev/null +++ b/Mortan/find_sql.sql @@ -0,0 +1,24 @@ +col sql_text for a60 wrap +set verify off +set pagesize 999 +set lines 155 +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 + +select sql_id, child_number, 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, +sql_text +from v$sql s +where upper(sql_text) like upper(nvl('&sql_text',sql_text)) +and sql_text not like '%from v$sql where sql_text like nvl(%' +and sql_id like nvl('&sql_id',sql_id) +order by 1, 2, 3 +/ diff --git a/Mortan/find_sql_awr.sql b/Mortan/find_sql_awr.sql new file mode 100644 index 0000000..246a5ae --- /dev/null +++ b/Mortan/find_sql_awr.sql @@ -0,0 +1,52 @@ +set long 32000 +set lines 155 +col sql_text format a40 +col execs for 999,999,999 +col etime for 999,999,999.9 +col avg_etime for 999,999.999 +col lio for 999,999,999,999 +col avg_lio for 999,999,999,999 +col avg_pio for 999,999,999,999 +col rows_proc for 999,999,999,999 head rows +col begin_interval_time for a30 +col node for 99999 +col versions for 99999 +col percent_of_total for 999.99 +break on report +compute sum of percent_of_total on report +select sql_id, sql_text, avg_pio, avg_lio, avg_etime, execs, rows_proc +from ( +select dbms_lob.substr(sql_text,3999,1) sql_text, b.* +from dba_hist_sqltext a, ( +select sql_id, sum(execs) execs, sum(etime) etime, sum(etime)/sum(execs) avg_etime, sum(pio)/sum(execs) avg_pio, +sum(lio)/sum(execs) avg_lio, sum(rows_proc) rows_proc +from ( +select ss.snap_id, ss.instance_number node, begin_interval_time, sql_id, +nvl(executions_delta,0) execs, +elapsed_time_delta/1000000 etime, +(elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime, +buffer_gets_delta lio, +disk_reads_delta pio, +rows_processed_delta rows_proc, +(buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio, +(rows_processed_delta/decode(nvl(rows_processed_delta,0),0,1,executions_delta)) avg_rows, +(disk_reads_delta/decode(nvl(disk_reads_delta,0),0,1,executions_delta)) avg_pio +from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS +where +ss.snap_id = S.snap_id +and ss.instance_number = S.instance_number +and ss.snap_id between nvl('&starting_snap_id',0) and nvl('&ending_snap_id',999999999) +and executions_delta > 0 +) +group by sql_id +order by 5 desc +) b +where a.sql_id = b.sql_id +and execs > 1 +) +where rownum <31 +and sql_text like nvl('&sql_text',sql_text) +and sql_id like nvl('&sql_id',sql_id) +-- group by sql_id, sql_text +order by etime desc +/ diff --git a/Mortan/find_sql_using_baseline.sql b/Mortan/find_sql_using_baseline.sql new file mode 100644 index 0000000..79cfae4 --- /dev/null +++ b/Mortan/find_sql_using_baseline.sql @@ -0,0 +1,26 @@ +col sql_text for a40 trunc +set verify off +set pagesize 999 +set lines 155 +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 + +select sql_id, child_number, plan_hash_value plan_hash, sql_plan_baseline, 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, +sql_text +from v$sql s +where upper(sql_text) like upper(nvl('&sql_text',sql_text)) +and sql_text not like '%from v$sql where sql_text like nvl(%' +and sql_id like nvl('&sql_id',sql_id) +and plan_hash_value like nvl('&plan_hash_value',plan_hash_value) +and sql_plan_baseline is not null +order by 1, 2, 3 +/ diff --git a/Mortan/find_sql_using_outline.sql b/Mortan/find_sql_using_outline.sql new file mode 100644 index 0000000..874cb1a --- /dev/null +++ b/Mortan/find_sql_using_outline.sql @@ -0,0 +1,25 @@ +col sql_text for a60 wrap +set verify off +set pagesize 999 +set lines 155 +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 + +select sql_id, child_number, 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, +sql_text +from v$sql s +where upper(sql_text) like upper(nvl('&sql_text',sql_text)) +and sql_text not like '%from v$sql where sql_text like nvl(%' +and sql_id like nvl('&sql_id',sql_id) +and outline_category is not null +order by 1, 2, 3 +/ diff --git a/Mortan/find_sql_using_profile.sql b/Mortan/find_sql_using_profile.sql new file mode 100644 index 0000000..7d55d7e --- /dev/null +++ b/Mortan/find_sql_using_profile.sql @@ -0,0 +1,27 @@ +break on sql_id on sql_profile on sql_text skip 1 +set lines 165 +col sql_profile for a30 +col sql_text for a60 wrap +set verify off +set pagesize 999 +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 + +select sql_id, child_number, plan_hash_value plan_hash, sql_profile, 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, +sql_text +from v$sql s +where upper(sql_text) like upper(nvl('&sql_text',sql_text)) +and sql_text not like '%from v$sql where sql_text like nvl(%' +and sql_id like nvl('&sql_id',sql_id) +and sql_profile is not null +order by 1, 2, 3 +/ diff --git a/Mortan/move_sql_profile.sql b/Mortan/move_sql_profile.sql new file mode 100644 index 0000000..42d0dd4 --- /dev/null +++ b/Mortan/move_sql_profile.sql @@ -0,0 +1,138 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: move_sql_profile.sql +-- +-- Purpose: Moves a SQL Profile from one statement to another. +- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for four values. +-- +-- profile_name: the name of the profile to be attached to a new statement +-- +-- sql_id: the sql_id of the statement to attach the profile to +-- +-- category: the category to assign to the new profile +-- +-- force_macthing: a toggle to turn on or off the force_matching feature +-- +-- Description: This script is based on a script originally written by Randolf Giest. +-- It's purpose is to allow a statements text to be manipulated in whatever +-- manner necessary (typically with hints) to get the desired plan. Then +-- once a SQL Profile has been created on the new statement, it's SQL Profile +-- can be moved (or attached) to the orignal statement with unmodified text. +-- +-- Mods: This script should now work wirh all flavors of 10g and 11g. +-- +-- +-- See kerryosborne.oracle-guy.com for additional information. +----------------------------------------------------------------------------------------- + +accept profile_name - + prompt 'Enter value for profile_name: ' - + default 'X0X0X0X0' +accept sql_id - + prompt 'Enter value for sql_id: ' - + default 'X0X0X0X0' +accept category - + prompt 'Enter value for category (DEFAULT): ' - + default 'DEFAULT' +accept force_matching - + prompt 'Enter value for force_matching (false): ' - + default 'false' + + +---------------------------------------------------------------------------------------- +-- +-- File name: profile_hints.sql +-- +--------------------------------------------------------------------------------------- +-- +set sqlblanklines on + +declare +ar_profile_hints sys.sqlprof_attr; +cl_sql_text clob; +version varchar2(3); +l_category varchar2(30); +l_force_matching varchar2(3); +b_force_matching boolean; +begin + select regexp_replace(version,'\..*') into version from v$instance; + +if version = '10' then + +-- dbms_output.put_line('version: '||version); + execute immediate -- to avoid 942 error + 'select attr_val as outline_hints '|| + 'from dba_sql_profiles p, sqlprof$attr h '|| + 'where p.signature = h.signature '|| + 'and name like (''&&profile_name'') '|| + 'order by attr#' + bulk collect + into ar_profile_hints; + +elsif version = '11' then + +-- dbms_output.put_line('version: '||version); + execute immediate -- to avoid 942 error + 'select hint as outline_hints '|| + 'from (select p.name, p.signature, p.category, row_number() '|| + ' over (partition by sd.signature, sd.category order by sd.signature) row_num, '|| + ' extractValue(value(t), ''/hint'') hint '|| + 'from sqlobj$data sd, dba_sql_profiles p, '|| + ' table(xmlsequence(extract(xmltype(sd.comp_data), '|| + ' ''/outline_data/hint''))) t '|| + 'where sd.obj_type = 1 '|| + 'and p.signature = sd.signature '|| + 'and p.name like (''&&profile_name'')) '|| + 'order by row_num' + bulk collect + into ar_profile_hints; + +end if; + + +/* +declare +ar_profile_hints sys.sqlprof_attr; +cl_sql_text clob; +begin +select attr_val as outline_hints +bulk collect +into +ar_profile_hints +from dba_sql_profiles p, sqlprof$attr h +where p.signature = h.signature +and name like ('&&profile_name') +order by attr#; +*/ + +select +sql_fulltext +into +cl_sql_text +from +v$sqlarea +where +sql_id = '&&sql_id'; + +dbms_sqltune.import_sql_profile( +sql_text => cl_sql_text +, profile => ar_profile_hints +, category => '&&category' +, name => 'PROFILE_'||'&&sql_id'||'_moved' +-- use force_match => true +-- to use CURSOR_SHARING=SIMILAR +-- behaviour, i.e. match even with +-- differing literals +, force_match => &&force_matching +); +end; +/ + +undef profile_name +undef sql_id +undef category +undef force_matching + diff --git a/Mortan/optim_parms.sql b/Mortan/optim_parms.sql new file mode 100644 index 0000000..1663d44 --- /dev/null +++ b/Mortan/optim_parms.sql @@ -0,0 +1,23 @@ +col child format 99999 +col name for a40 +col value for a40 +select * from ( +select +-- INST_ID, +-- KQLFSQCE_PHAD, +-- KQLFSQCE_HASH, +KQLFSQCE_SQLID sql_id, +-- KQLFSQCE_HADD, + KQLFSQCE_CHNO child, +-- KQLFSQCE_PNUM, + KQLFSQCE_PNAME name, + KQLFSQCE_PVALUE value, + decode(bitand(KQLFSQCE_FLAGS, 2), 0, 'NO', 'YES') isdefault +from X$KQLFSQCE +-- where bitand(KQLFSQCE_FLAGS, 8) = 0 +-- and (bitand(KQLFSQCE_FLAGS, 4) = 0 or bitand(KQLFSQCE_FLAGS, 2) = 0) +where KQLFSQCE_SQLID like nvl('&sql_id',KQLFSQCE_SQLID) +and decode(bitand(KQLFSQCE_FLAGS, 2), 0, 'NO', 'YES') like nvl('&isdefault','%') +) +order by 1,2 asc,decode(substr(name,1,1),'_',2,1), replace(name,'_','') +/ diff --git a/Mortan/outline_hints.sql b/Mortan/outline_hints.sql new file mode 100644 index 0000000..1a09449 --- /dev/null +++ b/Mortan/outline_hints.sql @@ -0,0 +1,4 @@ +select name, hint from dba_outline_hints +where name like nvl('&name',name) +and upper(hint) like upper(nvl('&hint',hint)) +/ diff --git a/Mortan/outlines.sql b/Mortan/outlines.sql new file mode 100644 index 0000000..9629451 --- /dev/null +++ b/Mortan/outlines.sql @@ -0,0 +1,22 @@ +set pagesize 999 +set lines 155 +column owner format a12 +column category format a15 +column name format a30 +col used for a12 +col enabled for a12 +column sql_text format a70 trunc +column hints for 99999 +break on owner +select category, ol_name name, + decode(bitand(flags, 1), 0, 'UNUSED', 1, 'USED') used, + decode(bitand(flags, 4), 0, 'ENABLED', 4, 'DISABLED') enabled, +hintcount hints, +sql_text +from outln.ol$ +where +category like nvl('&category',category) +and ol_name like nvl('&name',ol_name) +order by 1, 2, 4, 3 +/ + diff --git a/Mortan/pln.sql b/Mortan/pln.sql index eaadbc0..11f58d8 100644 --- a/Mortan/pln.sql +++ b/Mortan/pln.sql @@ -1,14 +1,14 @@ SELECT xplan.* -FROM - ( - select max(sql_id) keep - (dense_rank last order by last_active_time) sql_id - , max(child_number) keep - (dense_rank last order by last_active_time) child_number - from v$sql - where upper(sql_text) like '%&1%' - and upper(sql_text) not like '%FROM V$SQL WHERE UPPER(SQL_TEXT) LIKE %' - ) sqlinfo, - table(DBMS_XPLAN.DISPLAY_CURSOR(sqlinfo.sql_id, sqlinfo.child_number, 'ALLSTATS LAST')) xplan + FROM + ( + select max(sql_id) keep + (dense_rank last order by last_active_time) sql_id + , max(child_number) keep + (dense_rank last order by last_active_time) child_number + from v$sql + where upper(sql_text) like '%&1%' + and upper(sql_text) not like '%FROM V$SQL WHERE UPPER(SQL_TEXT) LIKE %' + ) sqlinfo, + table(DBMS_XPLAN.DISPLAY_CURSOR(sqlinfo.sql_id, sqlinfo.child_number, 'ALLSTATS LAST')) xplan / diff --git a/Mortan/restore_table_stats.sql b/Mortan/restore_table_stats.sql new file mode 100644 index 0000000..7ab8a14 --- /dev/null +++ b/Mortan/restore_table_stats.sql @@ -0,0 +1,7 @@ +begin + dbms_stats.restore_table_stats ( + '&Owner', + '&table_name', + '&as_of_date'||' 12.00.00.000000000 AM -04:00'); /* Noon */ +end; +/ diff --git a/Mortan/set_col_stats.sql b/Mortan/set_col_stats.sql new file mode 100644 index 0000000..a1cd2f5 --- /dev/null +++ b/Mortan/set_col_stats.sql @@ -0,0 +1,28 @@ +exec dbms_stats.set_column_stats(ownname => '&owner', tabname => '&table_name', colname => '&col_name', distcnt => &NDV, density => &density, nullcnt => &nullcnt, no_invalidate => false); +/* +PROCEDURE SET_COLUMN_STATS + Argument Name Type In/Out Default? + ------------------------------ ----------------------- ------ -------- + OWNNAME VARCHAR2 IN + TABNAME VARCHAR2 IN + COLNAME VARCHAR2 IN + PARTNAME VARCHAR2 IN DEFAULT + STATTAB VARCHAR2 IN DEFAULT + STATID VARCHAR2 IN DEFAULT + DISTCNT NUMBER IN DEFAULT + DENSITY NUMBER IN DEFAULT + NULLCNT NUMBER IN DEFAULT + SREC RECORD IN DEFAULT + EPC NUMBER IN DEFAULT + MINVAL RAW(2000) IN DEFAULT + MAXVAL RAW(2000) IN DEFAULT + BKVALS DBMS_STATS IN DEFAULT + NOVALS DBMS_STATS IN DEFAULT + CHVALS DBMS_STATS IN DEFAULT + EAVS NUMBER IN DEFAULT + AVGCLEN NUMBER IN DEFAULT + FLAGS NUMBER IN DEFAULT + STATOWN VARCHAR2 IN DEFAULT + NO_INVALIDATE BOOLEAN IN DEFAULT + FORCE BOOLEAN IN DEFAULT +*/ diff --git a/Mortan/sql_hints.sql b/Mortan/sql_hints.sql new file mode 100644 index 0000000..9fbb9fc --- /dev/null +++ b/Mortan/sql_hints.sql @@ -0,0 +1,15 @@ +select +extractvalue(value(d), '/hint') as outline_hints +from +xmltable('/*/outline_data/hint' +passing ( +select +xmltype(other_xml) as xmlval +from +v$sql_plan +where +sql_id like nvl('&sql_id',sql_id) +and child_number = &child_no +and other_xml is not null +) +) d; diff --git a/Mortan/sql_profile_hints.sql b/Mortan/sql_profile_hints.sql new file mode 100644 index 0000000..3c230d4 --- /dev/null +++ b/Mortan/sql_profile_hints.sql @@ -0,0 +1,84 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: sql_profile_hints.sql +-- +-- Purpose: Show hints associated with a SQL Profile. +- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for one value. +-- +-- profile_name: the name of the profile to be used +-- +-- Description: This script pulls the hints associated with a SQL Profile. +-- +-- Mods: Modified to check for 10g or 11g as the hint structure changed. +-- Modified to join on category as well as signature. +-- +-- See kerryosborne.oracle-guy.com for additional information. +--------------------------------------------------------------------------------------- +-- +set sqlblanklines on +set feedback off +accept profile_name - + prompt 'Enter value for profile_name: ' - + default 'X0X0X0X0' + +declare +ar_profile_hints sys.sqlprof_attr; +cl_sql_text clob; +version varchar2(3); +l_category varchar2(30); +l_force_matching varchar2(3); +b_force_matching boolean; +begin + select regexp_replace(version,'\..*') into version from v$instance; + +if version = '10' then + +-- dbms_output.put_line('version: '||version); + execute immediate -- to avoid 942 error + 'select attr_val as outline_hints '|| + 'from dba_sql_profiles p, sqlprof$attr h '|| + 'where p.signature = h.signature '|| + 'and p.category = h.category '|| + 'and name like (''&&profile_name'') '|| + 'order by attr#' + bulk collect + into ar_profile_hints; + +elsif version = '11' then + +-- dbms_output.put_line('version: '||version); + execute immediate -- to avoid 942 error + 'select hint as outline_hints '|| + 'from (select p.name, p.signature, p.category, row_number() '|| + ' over (partition by sd.signature, sd.category order by sd.signature) row_num, '|| + ' extractValue(value(t), ''/hint'') hint '|| + 'from sqlobj$data sd, dba_sql_profiles p, '|| + ' table(xmlsequence(extract(xmltype(sd.comp_data), '|| + ' ''/outline_data/hint''))) t '|| + 'where sd.obj_type = 1 '|| + 'and p.signature = sd.signature '|| + 'and p.category = sd.category '|| + 'and p.name like (''&&profile_name'')) '|| + 'order by row_num' + bulk collect + into ar_profile_hints; + +end if; + + dbms_output.put_line(' '); + dbms_output.put_line('HINT'); + dbms_output.put_line('------------------------------------------------------------------------------------------------------------------------------------------------------'); + for i in 1..ar_profile_hints.count loop + dbms_output.put_line(ar_profile_hints(i)); + end loop; + dbms_output.put_line(' '); + dbms_output.put_line(ar_profile_hints.count||' rows selected.'); + dbms_output.put_line(' '); + +end; +/ +undef profile_name +set feedback on diff --git a/Mortan/sql_profiles.sql b/Mortan/sql_profiles.sql new file mode 100644 index 0000000..390e452 --- /dev/null +++ b/Mortan/sql_profiles.sql @@ -0,0 +1,9 @@ +col category for a15 +col sql_text for a70 trunc +select name, category, status, sql_text, force_matching +from dba_sql_profiles +where sql_text like nvl('&sql_text','%') +and name like nvl('&name',name) +order by last_modified +/ + diff --git a/Mortan/unstable_plans.sql b/Mortan/unstable_plans.sql new file mode 100644 index 0000000..0c37de3 --- /dev/null +++ b/Mortan/unstable_plans.sql @@ -0,0 +1,54 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: unstable_plans.sql +-- +-- Purpose: Attempts to find SQL statements with plan instability. +-- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for two values, both of which can be left blank. +-- +-- min_stddev: the minimum "normalized" standard deviation between plans +-- (the default is 2) +-- +-- min_etime: only include statements that have an avg. etime > this value +-- (the default is .1 second) +-- +-- See http://kerryosborne.oracle-guy.com/2008/10/unstable-plans/ for more info. +--------------------------------------------------------------------------------------- + +set lines 155 +col execs for 999,999,999 +col min_etime for 999,999.99 +col max_etime for 999,999.99 +col avg_etime for 999,999.999 +col avg_lio for 999,999,999.9 +col norm_stddev for 999,999.9999 +col begin_interval_time for a30 +col node for 99999 +break on plan_hash_value on startup_time skip 1 +select * from ( +select sql_id, sum(execs), min(avg_etime) min_etime, max(avg_etime) max_etime, stddev_etime/min(avg_etime) norm_stddev +from ( +select sql_id, plan_hash_value, execs, avg_etime, +stddev(avg_etime) over (partition by sql_id) stddev_etime +from ( +select sql_id, plan_hash_value, +sum(nvl(executions_delta,0)) execs, +(sum(elapsed_time_delta)/decode(sum(nvl(executions_delta,0)),0,1,sum(executions_delta))/1000000) avg_etime +-- sum((buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta))) avg_lio +from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS +where ss.snap_id = S.snap_id +and ss.instance_number = S.instance_number +and executions_delta > 0 +and elapsed_time_delta > 0 +and s.snap_id > nvl('&earliest_snap_id',0) +group by sql_id, plan_hash_value +) +) +group by sql_id, stddev_etime +) +where norm_stddev > nvl(to_number('&min_stddev'),2) +and max_etime > nvl(to_number('&min_etime'),.1) +order by norm_stddev +/ diff --git a/Mortan/whats_changed.sql b/Mortan/whats_changed.sql new file mode 100644 index 0000000..2167808 --- /dev/null +++ b/Mortan/whats_changed.sql @@ -0,0 +1,122 @@ +---------------------------------------------------------------------------------------- +-- +-- File name: whats_changed.sql +-- +-- Purpose: Find statements that have significantly different elapsed time than before. +- +-- Author: Kerry Osborne +-- +-- Usage: This scripts prompts for four values. +-- +-- days_ago: how long ago was the change made that you wish to evaluate +-- (this could easily be changed to a snap_id for more precision) +-- +-- min_stddev: the minimum "normalized" standard deviation between plans +-- (the default is 2 - which means twice as fast/slow) +-- +-- min_etime: only include statements that have an avg. etime > this value +-- (the default is .1 second) +-- +-- +-- faster_slower: a flag to indicate if you want only Faster or Slower SQL +-- (the default is both - use S% for slower and F% for faster) +-- +-- Description: This scripts attempts to find statements with significantly different +-- average elapsed times per execution. It uses AWR data and computes a +-- normalized standard deviation between the average elapsed time per +-- execution before and after the date specified by the days_ago parameter. +-- +-- The ouput includes the following: +-- +-- SQL_ID - the sql_id of a statement that is in the shared pool (v$sqlarea) +-- +-- EXECS - the total number of executions in the AWR tables +-- +-- AVG_ETIME_BEFORE - the average elapsed time per execution before the REFERENCE_TIME +-- +-- AVG_ETIME_AFTER - the average elapsed time per execution after the REFERENCE_TIME +-- +-- NORM_STDDEV - this is a normalized standard deviation (i.e. how many times slower/faster is it now) +-- +-- See http://kerryosborne.oracle-guy.com for additional information. +---------------------------------------------------------------------------------------- + +accept days_ago - + prompt 'Enter Days ago: ' - + default '1' + +set lines 155 +col execs for 999,999,999 +col before_etime for 999,990.99 +col after_etime for 999,990.99 +col before_avg_etime for 999,990.99 head AVG_ETIME_BEFORE +col after_avg_etime for 999,990.99 head AVG_ETIME_AFTER +col min_etime for 999,990.99 +col max_etime for 999,990.99 +col avg_etime for 999,990.999 +col avg_lio for 999,999,990.9 +col norm_stddev for 999,990.9999 +col begin_interval_time for a30 +col node for 99999 +break on plan_hash_value on startup_time skip 1 +select * from ( +select sql_id, execs, before_avg_etime, after_avg_etime, norm_stddev, + case when to_number(before_avg_etime) < to_number(after_avg_etime) then 'Slower' else 'Faster' end result +-- select * +from ( +select sql_id, sum(execs) execs, sum(before_execs) before_execs, sum(after_execs) after_execs, + sum(before_avg_etime) before_avg_etime, sum(after_avg_etime) after_avg_etime, + min(avg_etime) min_etime, max(avg_etime) max_etime, stddev_etime/min(avg_etime) norm_stddev, + case when sum(before_avg_etime) > sum(after_avg_etime) then 'Slower' else 'Faster' end better_or_worse +from ( +select sql_id, + period_flag, + execs, + avg_etime, + stddev_etime, + case when period_flag = 'Before' then execs else 0 end before_execs, + case when period_flag = 'Before' then avg_etime else 0 end before_avg_etime, + case when period_flag = 'After' then execs else 0 end after_execs, + case when period_flag = 'After' then avg_etime else 0 end after_avg_etime +from ( +select sql_id, period_flag, execs, avg_etime, +stddev(avg_etime) over (partition by sql_id) stddev_etime +from ( +select sql_id, period_flag, sum(execs) execs, sum(etime)/sum(decode(execs,0,1,execs)) avg_etime from ( +select sql_id, 'Before' period_flag, +nvl(executions_delta,0) execs, +(elapsed_time_delta)/1000000 etime +-- sum((buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta))) avg_lio +from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS +where ss.snap_id = S.snap_id +and ss.instance_number = S.instance_number +and executions_delta > 0 +and elapsed_time_delta > 0 +and ss.begin_interval_time <= sysdate-&&days_ago +union +select sql_id, 'After' period_flag, +nvl(executions_delta,0) execs, +(elapsed_time_delta)/1000000 etime +-- (elapsed_time_delta)/decode(nvl(executions_delta,0),0,1,executions_delta)/1000000 avg_etime +-- sum((buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta))) avg_lio +from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS +where ss.snap_id = S.snap_id +and ss.instance_number = S.instance_number +and executions_delta > 0 +and elapsed_time_delta > 0 +and ss.begin_interval_time > sysdate-&&days_ago +-- and s.snap_id > 7113 +) +group by sql_id, period_flag +) +) +) +group by sql_id, stddev_etime +) +where norm_stddev > nvl(to_number('&min_stddev'),2) +and max_etime > nvl(to_number('&min_etime'),.1) +) +where result like nvl('&Faster_Slower',result) +order by norm_stddev +/ +