Skip to content

Commit

Permalink
work copy
Browse files Browse the repository at this point in the history
  • Loading branch information
xtender committed Mar 25, 2015
1 parent 0026db1 commit 68b2019
Show file tree
Hide file tree
Showing 16 changed files with 450 additions and 21 deletions.
131 changes: 131 additions & 0 deletions awr/asqlmon11.sql
@@ -0,0 +1,131 @@
@inc/input_vars_init.sql;
set termout off
COL _if_projection NEW_VALUE _if_projection NOPRINT
COL _if_predicates NEW_VALUE _if_predicates NOPRINT
select case when '&2 &3 &4 &5' like '%+proj%' then ' ' else '--' end "_if_projection"
,case when '&2 &3 &4 &5' like '%+pred%' then ' ' else '--' end "_if_predicates"
from dual;
set termout on
------------------------------------------------------------------------------------------------------------------------
--
-- File name: asqlmon.sql (v1.0)
--
-- Purpose: Report SQL-monitoring-style drill-down into where in an execution plan the execution time is spent
--
-- Author: Tanel Poder
--
-- Copyright: (c) http://blog.tanelpoder.com - All rights reserved.
--
-- Disclaimer: This script is provided "as is", no warranties nor guarantees are
-- made. Use at your own risk :)
--
-- Usage: @asqlmon <sqlid> <child#>
--
-- Notes: This script runs on Oracle 11g+ and you should have the
-- Diagnostics and Tuning pack licenses for using it as it queries
-- some separately licensed views.
--
------------------------------------------------------------------------------------------------------------------------

COL asqlmon_operation FOR a80
COL asqlmon_predicates FOR a100 word_wrap
COL options FOR a30

COL asqlmon_plan_hash_value HEAD PLAN_HASH_VALUE
COL asqlmon_sql_id HEAD SQL_ID NOPRINT
COL asqlmon_sql_child HEAD CHILD#
COL asqlmon_sample_time HEAD SAMPLE_HOUR
COL obj_alias_qbc_name for a30
COL event FOR A50
COL projection FOR A150

COL pct_child HEAD "Activity %" FOR A8
COL pct_child_vis HEAD "Visual" FOR A12

COL asqlmon_id HEAD "Line ID" FOR 9999
COL asqlmon_parent_id HEAD "Parent" FOR 9999


rem BREAK ON asqlmon_plan_hash_value SKIP 1 ON asqlmon_sql_id SKIP 1 ON asqlmon_sql_child SKIP 1 ON asqlmon_sample_time SKIP 1 DUP ON asqlmon_operation
BREAK ON asqlmon_sql_id SKIP 1 ON snap_id SKIP 1 ON asqlmon_plan_hash_value SKIP 1 ON secs_by_plan_line SKIP 1 DUP

WITH
snaps as (
select distinct st.dbid, st.snap_id, st.instance_number,st.sql_id,st.plan_hash_value
from dba_hist_sqlstat st
where st.sql_id='&1'
and st.plan_hash_value like '%&2%'
)
,sq AS (
SELECT
-- to_char(ash.sample_time, 'YYYY-MM-DD HH24') sample_time
count(*) samples
, sum(count(*)) over(partition by ash.sql_id,ash.snap_id,ash.sql_plan_line_id) samples_by_line
, ash.sql_id
, ash.snap_id
, ash.sql_plan_hash_value
, ash.sql_plan_line_id
, ash.sql_plan_operation
, ash.sql_plan_options
, ash.session_state
, ash.event
FROM
snaps s
,dba_hist_active_sess_history ash
WHERE
1=1
AND s.dbid = ash.dbid
and s.snap_id = ash.snap_id
and s.instance_number = ash.instance_number
and s.sql_id = ash.sql_id
AND s.plan_hash_value = ash.sql_plan_hash_value
--AND ash.session_id = 8 AND ash.session_serial# = 35019
GROUP BY
--to_char(ash.sample_time, 'YYYY-MM-DD HH24')
ash.sql_id
, ash.snap_id
, ash.sql_plan_hash_value
, ash.sql_plan_line_id
, ash.sql_plan_operation
, ash.sql_plan_options
, ash.session_state
, ash.event
)
SELECT
plan.sql_id as asqlmon_sql_id
, plan.plan_hash_value as asqlmon_plan_hash_value
, sq.snap_id
, sq.samples_by_line as secs_by_plan_line
, sq.samples as seconds
, LPAD(TO_CHAR(ROUND(RATIO_TO_REPORT(sq.samples) OVER (PARTITION BY sq.sql_id, sq.sql_plan_hash_value) * 100, 1), 999.9)||' %',8) as pct_child
, '|'||RPAD( NVL( LPAD('#', ROUND(RATIO_TO_REPORT(sq.samples) OVER (PARTITION BY sq.sql_id, sq.sql_plan_hash_value) * 10), '#'), ' '), 10,' ')||'|' as pct_child_vis
--, sq.sample_time asqlmon_sample_time
--, LPAD(plan.id,4)||CASE WHEN parent_id IS NULL THEN ' ' ELSE ' <- ' END||LPAD(plan.parent_id,4) asqlmon_plan_id
, plan.id as asqlmon_id
, plan.parent_id as asqlmon_parent_id
, LPAD(' ', depth) || plan.operation ||' '|| plan.options || NVL2(plan.object_name, ' ['||plan.object_name ||']', null) as asqlmon_operation
, sq.session_state
, sq.event
, plan.object_alias || CASE WHEN plan.qblock_name IS NOT NULL THEN ' ['|| plan.qblock_name || ']' END as obj_alias_qbc_name
&_if_predicates , CASE WHEN plan.access_predicates IS NOT NULL THEN ' [A:] '|| plan.access_predicates END
&_if_predicates || CASE WHEN plan.filter_predicates IS NOT NULL THEN ' [F:]' || plan.filter_predicates END as asqlmon_predicates
&_if_projection , plan.projection
FROM
dba_hist_sql_plan plan
, sq
WHERE
1=1
AND sq.sql_id(+) = plan.sql_id
AND sq.sql_plan_line_id(+) = plan.id
AND sq.sql_plan_hash_value(+) = plan.plan_hash_value
AND plan.sql_id = '&1'
and plan.plan_hash_value like '%&2%'
ORDER BY
--sq.sample_time
sq.snap_id
, plan.plan_hash_value
, plan.id
, sq.samples desc
/
clear BREAKs
@inc/input_vars_undef.sql;
24 changes: 24 additions & 0 deletions awr/sql_by_signature.sql
@@ -0,0 +1,24 @@
@inc/input_vars_init;
col force_matching_signature new_value sign_force for a25
col exact_matching_signature new_value sign_exact for a25
col profile for a30;

select to_char(sn.begin_interval_time,'yyyy-mm-dd hh24:mi') beg_time
,sn.snap_id
,s.sql_id
,s.plan_hash_value
,s.elapsed_time_delta/nullif(s.executions_delta,0)/1e6 ela_exe
,s.executions_delta cnt
,s.sql_profile profile
,to_char(s.force_matching_signature,'tm9') force_matching_signature
from dba_hist_sqlstat s
,dba_hist_snapshot sn
where
s.force_matching_signature in (&1,&2)
and s.dbid = sn.dbid
and s.snap_id = sn.snap_id
and s.instance_number = sn.instance_number
order by sn.snap_id desc, s.plan_hash_value, s.sql_id;

col profile clear;
@inc/input_vars_undef;
26 changes: 26 additions & 0 deletions dump_seg_blocks.sql
@@ -0,0 +1,26 @@
accept trace_identifier prompt "Trace identifier: ";
accept ownname prompt "Segment owner: ";
accept segname prompt "Segment name: ";

alter session set tracefile_identifier='&trace_identifier';

prompt Tracing was enabled:
select par.value ||'/'||(select instance_name from v$instance) ||'_ora_'||s.suffix|| '.trc' as tracefile_name
from
v$parameter par
, (select spid||case when traceid is not null then '_'||traceid else null end suffix
from v$process where addr = (select paddr from v$session
where sid = userenv('sid')
)
) s
where name = 'user_dump_dest';

begin
for rec in (select file_id, block_id start_block, block_id + blocks - 1 end_block from dba_extents where segment_name = '&segname' and owner = '&ownname') loop
execute immediate 'alter system dump datafile ' || rec.file_id || ' block min ' || rec.start_block || ' block max ' || rec.end_block;
end loop;
end;
/
undef trace_identifier ownname segname;
alter session set tracefile_identifier=CLEANUP;
alter session set tracefile_identifier=new;
6 changes: 6 additions & 0 deletions find_sql.sql
@@ -1,16 +1,22 @@
@inc/input_vars_init
prompt Show only first 30 found:

col if_all new_val _if_all noprint;

select case when '&2 &3 &4 &5' like '%all%' then '--'
else ' '
end if_all
from dual;

col sql_id format a13;
col signature format a21;
col sql_text_trunc format a100 word;
col to_purge format a30;

SELECT/*+NOTME*/
inst_id
, sa.sql_id
, to_char(sa.force_matching_signature,'tm9') as signature
, sa.ADDRESS || ',' || sa.HASH_VALUE as to_purge
, sa.plan_hash_value as phv
, sa.executions as execs
Expand Down
48 changes: 48 additions & 0 deletions hinth.sql
@@ -0,0 +1,48 @@
--------------------------------------------------------------------------------
--
-- File name: hinth.sql (Hint Hierarchy)
--
-- Purpose: Display the areas / features in Oracle kernel that a hint affects
-- (displayed as a feature/module hierarchy)
--
-- Author: Tanel Poder
-- Copyright: (c) http://www.tanelpoder.com
--
-- Usage: @hinth <hint_name>
-- @hinth MERGE
--
-- Other: Requires Oracle 11g+
--
--------------------------------------------------------------------------------

COL sqlfh_feature HEAD SQL_FEATURE FOR A55
COL hinth_path HEAD PATH FOR A150

PROMPT Display Hint feature hierarchy for hints like &1

WITH feature_hierarchy AS (
SELECT
f.sql_feature
, SYS_CONNECT_BY_PATH(REPLACE(f.sql_feature, 'QKSFM_', ''), ' -> ') path
FROM
v$sql_feature f
, v$sql_feature_hierarchy fh
WHERE
f.sql_feature = fh.sql_feature
CONNECT BY fh.parent_id = PRIOR f.sql_Feature
START WITH fh.sql_feature = 'QKSFM_ALL'
)
SELECT
hi.name
, REGEXP_REPLACE(fh.path, '^ -> ', '') hinth_path
FROM
v$sql_hint hi
, feature_hierarchy fh
WHERE
hi.sql_feature = fh.sql_feature
-- hi.sql_feature = REGEXP_REPLACE(fh.sql_feature, '_[[:digit:]]+$')
AND UPPER(hi.name) LIKE UPPER('%&1%')
ORDER BY
path
--name
/
27 changes: 27 additions & 0 deletions rtsm/find_sql.sql
@@ -0,0 +1,27 @@
@inc/input_vars_init
prompt Show only first 30 found:

col sql_id format a13;
col signature format a21;
col sql_text_trunc format a100 word;
col to_purge format a30;

SELECT/*+NOTME*/
inst_id
, sa.sql_id
, sa.sql_exec_start
, sa.status
, to_char(sa.force_matching_signature,'tm9') as signature
, sa.sql_plan_hash_value as phv
, sa.elapsed_time/1e6 as elaexe
, substr(sql_text,1,300) as sql_text_trunc
FROM gv$sql_monitor sa
where
upper(sa.sql_text) like upper(q'[&1]')
and sql_text not like 'SELECT/*+NOTME*/%'
and rownum<=30
order by sa.sql_exec_start desc, elapsed_time desc
/
col sql_id clear;
col sql_text_trunc clear;
col to_purge clear;
40 changes: 21 additions & 19 deletions rtsm/sqlid_exec.sql
@@ -1,33 +1,35 @@
prompt eXplain with Profile: Running DBMS_SQLTUNE.REPORT_SQL_MONITOR for SQL_ID='&1' and EXEC_ID='&2'....

@inc/input_vars_init;
set termout off timing off ver off feed off head off lines 32767 pagesize 0
-------------------------
col sqlmon format a300;

-- workaround for bug with:
-- ORA-06502: PL/SQL: numeric or value error
-- ORA-06512: at "SYS.DBMS_SQLTUNE", line 14265
set termout off;
col nls_num_chars new_val nls_num_chars noprint;
select value nls_num_chars from nls_session_parameters where parameter='NLS_NUMERIC_CHARACTERS';
alter session set nls_numeric_characters='.,';
-------------------------
define MON_SQLID ="&1"
define MON_SQLEXEC ="&2"
define MON_FILE=&_TEMPDIR\xprof_&MON_SQLID._&MON_SQLEXEC..html
spool &MON_FILE

SELECT
DBMS_SQLTUNE.REPORT_SQL_MONITOR(
SQL_ID => '&MON_SQLID',
sql_exec_id => '&MON_SQLEXEC',

-- main part:
set termout on;
SELECT/*+ no_monitor */
DBMS_SQLTUNE.REPORT_SQL_MONITOR(
SQL_ID => '&1',
sql_exec_id => '&2',
report_level => 'ALL',
type => 'ACTIVE') as report
type => 'TEXT'
) as sqlmon
FROM dual
/
spool off
host &_START &MON_FILE
-------------------------
set termout off
-- end main part


-- restore all:
alter session set nls_numeric_characters='&nls_num_chars';
undef nls_num_chars;
-------------------------
undef MON_FILE MON_SQLID MON_SQLEXEC
col sqlmon clear;
undef 1 nls_num_chars;

set termout on;
@inc/input_vars_undef;
33 changes: 33 additions & 0 deletions rtsm/sqlid_exec_html.sql
@@ -0,0 +1,33 @@
prompt eXplain with Profile: Running DBMS_SQLTUNE.REPORT_SQL_MONITOR for SQL_ID='&1' and EXEC_ID='&2'....

@inc/input_vars_init;
set termout off timing off ver off feed off head off lines 32767 pagesize 0
-------------------------
-- workaround for bug with:
-- ORA-06502: PL/SQL: numeric or value error
-- ORA-06512: at "SYS.DBMS_SQLTUNE", line 14265
col nls_num_chars new_val nls_num_chars noprint;
select value nls_num_chars from nls_session_parameters where parameter='NLS_NUMERIC_CHARACTERS';
alter session set nls_numeric_characters='.,';
-------------------------
define MON_SQLID ="&1"
define MON_SQLEXEC ="&2"
define MON_FILE=&_TEMPDIR\xprof_&MON_SQLID._&MON_SQLEXEC..html
spool &MON_FILE

SELECT
DBMS_SQLTUNE.REPORT_SQL_MONITOR(
SQL_ID => '&MON_SQLID',
sql_exec_id => '&MON_SQLEXEC',
report_level => 'ALL',
type => 'ACTIVE') as report
FROM dual
/
spool off
host &_START &MON_FILE
-------------------------
alter session set nls_numeric_characters='&nls_num_chars';
undef nls_num_chars;
-------------------------
undef MON_FILE MON_SQLID MON_SQLEXEC
@inc/input_vars_undef;
4 changes: 2 additions & 2 deletions sessions.sql
Expand Up @@ -4,12 +4,12 @@ col inst_id format 9999;
col osuser format a18;
col process format a12;
col program format a20;
col module format a20;
col module format a20 trunc;
col terminal format a20;
col client_id format a20;
col type format a10;
col sql_id format a13;
col action format a17;
col action format a17 trunc;
col event format a30;
col wait_class format a20;
col sql_exec_start format a19;
Expand Down

0 comments on commit 68b2019

Please sign in to comment.