Skip to content

Commit 2c728b3

Browse files
committed
new stuff before vconf
1 parent 73be30d commit 2c728b3

14 files changed

+423
-20
lines changed

ash/ash_index_helper.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -32,7 +32,7 @@ PROMPT
3232
PROMPT -- Santa's Little (Index) Helper BETA v0.5 - by Tanel Poder ( https://tanelpoder.com )
3333

3434
WITH
35-
tab AS (SELECT /*+ MATERIALIZE */ owner, table_name, num_rows
35+
tab AS (SELECT /*+ NO_MERGE */ owner, table_name, num_rows
3636
FROM dba_tables
3737
WHERE UPPER(table_name) LIKE
3838
UPPER(CASE
@@ -49,7 +49,7 @@ tab AS (SELECT /*+ MATERIALIZE */ owner, table_name, num_rows
4949
user
5050
END ESCAPE '\'
5151
),
52-
ind AS (SELECT /*+ MATERIALIZE */ owner, index_name, table_owner, table_name
52+
ind AS (SELECT /*+ NO_MERGE */ owner, index_name, table_owner, table_name
5353
FROM dba_indexes
5454
WHERE (table_owner, table_name) IN (SELECT owner, table_name FROM tab)),
5555
sample_times AS (

ash/ash_index_helperx.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -32,7 +32,7 @@ PROMPT
3232
PROMPT -- Santa's Little (Index) Helper BETA v0.5 - by Tanel Poder ( https://tanelpoder.com )
3333

3434
WITH
35-
tab AS (SELECT /*+ MATERIALIZE */ owner, table_name, num_rows
35+
tab AS (SELECT /*+ NO_MERGE */ owner, table_name, num_rows
3636
FROM dba_tables
3737
WHERE UPPER(table_name) LIKE
3838
UPPER(CASE
@@ -49,7 +49,7 @@ tab AS (SELECT /*+ MATERIALIZE */ owner, table_name, num_rows
4949
user
5050
END ESCAPE '\'
5151
),
52-
ind AS (SELECT /*+ MATERIALIZE */ owner, index_name, table_owner, table_name
52+
ind AS (SELECT /*+ NO_MERGE */ owner, index_name, table_owner, table_name
5353
FROM dba_indexes
5454
WHERE (table_owner, table_name) IN (SELECT owner, table_name FROM tab)),
5555
sample_times AS (

ash/ash_object_predicates.sql

Lines changed: 118 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,118 @@
1+
-- Copyright 2018 Tanel Poder. All rights reserved. More info at http://tanelpoder.com
2+
-- Licensed under the Apache License, Version 2.0. See LICENSE.txt for terms & conditions.
3+
4+
SET LINESIZE 999 PAGESIZE 5000 TRIMOUT ON TRIMSPOOL ON
5+
6+
COL asqlmon_operation HEAD Plan_Operation FOR a72
7+
COL asqlmon_predicates HEAD PREDICATES FOR a100 word_wrap
8+
COL obj_alias_qbc_name FOR a40
9+
COL options FOR a30
10+
11+
COL asqlmon_plan_hash_value HEAD PLAN_HASH_VALUE PRINT
12+
COL asqlmon_sql_id HEAD SQL_ID NOPRINT
13+
COL asqlmon_sql_child HEAD "CHILD" PRINT
14+
COL asqlmon_sample_time HEAD SAMPLE_HOUR
15+
COL projection FOR A520
16+
17+
COL pct_child HEAD "Activity %" FOR A8
18+
COL pct_child_vis HEAD "Visual" FOR A12
19+
20+
COL asqlmon_id HEAD "ID" FOR 9999
21+
COL asqlmon_parent_id HEAD "PID" FOR 9999
22+
23+
24+
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
25+
26+
PROMPT
27+
PROMPT -- ASQLMon v1.1 - by Tanel Poder ( http://blog.tanelpoder.com ) - Display SQL execution plan line level activity breakdown from ASH
28+
29+
WITH sample_times AS (
30+
select * from dual
31+
),
32+
sq AS (
33+
SELECT
34+
count(*) samples
35+
, ash.sql_id
36+
, ash.sql_child_number
37+
, ash.sql_plan_hash_value
38+
, NVL(ash.sql_plan_line_id,1) sql_plan_line_id -- this is because simple "planless" operations like single-row insert
39+
, ash.sql_plan_operation
40+
, ash.sql_plan_options
41+
, ash.session_state
42+
, ash.event
43+
-- , AVG(ash.p3) avg_p3 -- p3 is sometimes useful for listing block counts for IO wait events
44+
FROM
45+
v$active_session_history ash
46+
WHERE
47+
1=1
48+
AND ash.sql_plan_operation IN ('TABLE ACCESS', 'INDEX')
49+
AND ash.sql_id LIKE '&1'
50+
AND ash.sql_child_number LIKE '&2'
51+
AND ash.sample_time BETWEEN &3 AND &4
52+
GROUP BY
53+
ash.sql_id
54+
, ash.sql_child_number
55+
, ash.sql_plan_hash_value
56+
, NVL(ash.sql_plan_line_id,1)
57+
, ash.sql_plan_operation
58+
, ash.sql_plan_options
59+
, ash.session_state
60+
, ash.event
61+
),
62+
ash_and_plan AS (
63+
SELECT
64+
plan.sql_id
65+
, plan.child_number
66+
, plan.plan_hash_value
67+
, sq.samples seconds
68+
, 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) pct_child
69+
, '|'||RPAD( NVL( LPAD('#', ROUND(RATIO_TO_REPORT(sq.samples) OVER (PARTITION BY sq.sql_id, sq.sql_plan_hash_value) * 10), '#'), ' '), 10,' ')||'|' pct_child_vis
70+
--, LPAD(plan.id,4)||CASE WHEN parent_id IS NULL THEN ' ' ELSE ' <- ' END||LPAD(plan.parent_id,4) asqlmon_plan_id
71+
, plan.id asqlmon_id
72+
, plan.parent_id asqlmon_parent_id
73+
, plan.operation ||' '|| plan.options || NVL2(plan.object_name, ' ['||plan.object_name ||']', null) asqlmon_operation
74+
, sq.session_state
75+
, sq.event
76+
-- , sq.avg_p3
77+
, plan.object_alias || CASE WHEN plan.qblock_name IS NOT NULL THEN ' ['|| plan.qblock_name || ']' END obj_alias_qbc_name
78+
, CASE WHEN plan.access_predicates IS NOT NULL THEN '[A:] '|| SUBSTR(plan.access_predicates,1,1994) END || CASE WHEN plan.filter_predicates IS NOT NULL THEN ' [F:] ' || SUBSTR(plan.filter_predicates,1,1994) END asqlmon_predicates
79+
-- , plan.projection
80+
FROM
81+
v$sql_plan plan
82+
, sq
83+
WHERE
84+
1=1
85+
AND sq.sql_id(+) = plan.sql_id
86+
AND sq.sql_child_number(+) = plan.child_number
87+
AND sq.sql_plan_line_id(+) = plan.id
88+
AND sq.sql_plan_hash_value(+) = plan.plan_hash_value
89+
AND plan.sql_id LIKE '&1'
90+
AND plan.child_number LIKE '&2'
91+
)
92+
SELECT * FROM (
93+
SELECT
94+
SUM(seconds) seconds
95+
, asqlmon_operation
96+
, session_state
97+
-- , event
98+
-- , obj_alias_qbc_name
99+
, asqlmon_predicates
100+
, COUNT(DISTINCT sql_id) dist_sqlids
101+
, COUNT(DISTINCT plan_hash_value) dist_plans
102+
, MIN(sql_id)
103+
, MAX(sql_id)
104+
FROM
105+
ash_and_plan
106+
WHERE
107+
seconds > 0
108+
GROUP BY
109+
asqlmon_operation
110+
, session_state
111+
-- , event
112+
-- , obj_alias_qbc_name
113+
, asqlmon_predicates
114+
ORDER BY
115+
seconds DESC
116+
)
117+
WHERE rownum <= 30
118+
/

ash/ashtop.sql

Lines changed: 4 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -33,8 +33,9 @@ COL p2hex FOR A17
3333
COL p3hex FOR A17
3434
COL dop FOR 99
3535
COL AAS FOR 9999.9
36-
COL totalseconds HEAD "Total|Seconds" FOR 99999999
37-
COL dist_sqlexec_seen HEAD "Distinct|Execs Seen" FOR 999999
36+
COL totalseconds HEAD "Total|Seconds" FOR 99999999
37+
COL dist_sqlexec_seen HEAD "Distinct|Execs Seen" FOR 999999
38+
COL dist_timestamps HEAD "Distinct|Tstamps" FOR 999999
3839
COL event FOR A42 WORD_WRAP
3940
COL event2 FOR A42 WORD_WRAP
4041
COL time_model_name FOR A50 WORD_WRAP
@@ -59,6 +60,7 @@ FROM (
5960
, TO_CHAR(MAX(sample_time), 'YYYY-MM-DD HH24:MI:SS') last_seen
6061
-- , MAX(sql_exec_id) - MIN(sql_exec_id)
6162
, COUNT(DISTINCT sql_exec_start||':'||sql_exec_id) dist_sqlexec_seen
63+
, COUNT(DISTINCT sample_time) dist_timestamps
6264
FROM
6365
(SELECT
6466
a.*

ash/ashtop10.sql

Lines changed: 104 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,104 @@
1+
-- Copyright 2018 Tanel Poder. All rights reserved. More info at http://tanelpoder.com
2+
-- Licensed under the Apache License, Version 2.0. See LICENSE.txt for terms & conditions.
3+
4+
--------------------------------------------------------------------------------
5+
--
6+
-- File name: ashtop.sql v1.2
7+
-- Purpose: Display top ASH time (count of ASH samples) grouped by your
8+
-- specified dimensions
9+
--
10+
-- Author: Tanel Poder
11+
-- Copyright: (c) http://blog.tanelpoder.com
12+
--
13+
-- Usage:
14+
-- @ashtop <grouping_cols> <filters> <fromtime> <totime>
15+
--
16+
-- Example:
17+
-- @ashtop username,sql_id session_type='FOREGROUND' sysdate-1/24 sysdate
18+
--
19+
-- Other:
20+
-- This script uses only the in-memory GV$ACTIVE_SESSION_HISTORY, use
21+
-- @dashtop.sql for accessiong the DBA_HIST_ACTIVE_SESS_HISTORY archive
22+
--
23+
--------------------------------------------------------------------------------
24+
COL "%This" FOR A7
25+
--COL p1 FOR 99999999999999
26+
--COL p2 FOR 99999999999999
27+
--COL p3 FOR 99999999999999
28+
COL p1text FOR A30 word_wrap
29+
COL p2text FOR A30 word_wrap
30+
COL p3text FOR A30 word_wrap
31+
COL p1hex FOR A17
32+
COL p2hex FOR A17
33+
COL p3hex FOR A17
34+
COL AAS FOR 9999.9
35+
COL totalseconds HEAD "Total|Seconds" FOR 99999999
36+
COL dist_sqlexec_seen HEAD "Distinct|Execs Seen" FOR 999999
37+
COL event FOR A42 WORD_WRAP
38+
COL event2 FOR A42 WORD_WRAP
39+
COL time_model_name FOR A50 WORD_WRAP
40+
COL program2 FOR A40 TRUNCATE
41+
COL username FOR A20 wrap
42+
COL obj FOR A30
43+
COL objt FOR A50
44+
COL sql_opname FOR A20
45+
COL top_level_call_name FOR A30
46+
COL wait_class FOR A15
47+
48+
SELECT
49+
*
50+
FROM (
51+
WITH bclass AS (SELECT class, ROWNUM r from v$waitstat)
52+
SELECT /*+ LEADING(a) USE_HASH(u) */
53+
COUNT(*) totalseconds
54+
, ROUND(COUNT(*) / ((CAST(&4 AS DATE) - CAST(&3 AS DATE)) * 86400), 1) AAS
55+
, LPAD(ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100)||'%',5,' ')||' |' "%This"
56+
, &1
57+
, TO_CHAR(MIN(sample_time), 'YYYY-MM-DD HH24:MI:SS') first_seen
58+
, TO_CHAR(MAX(sample_time), 'YYYY-MM-DD HH24:MI:SS') last_seen
59+
FROM
60+
(SELECT
61+
a.*
62+
, session_id sid
63+
, session_serial# serial
64+
, TO_CHAR(CASE WHEN session_state = 'WAITING' THEN p1 ELSE null END, '0XXXXXXXXXXXXXXX') p1hex
65+
, TO_CHAR(CASE WHEN session_state = 'WAITING' THEN p2 ELSE null END, '0XXXXXXXXXXXXXXX') p2hex
66+
, TO_CHAR(CASE WHEN session_state = 'WAITING' THEN p3 ELSE null END, '0XXXXXXXXXXXXXXX') p3hex
67+
, NVL(event, session_state)||
68+
CASE
69+
WHEN event like 'enq%' AND session_state = 'WAITING'
70+
THEN ' [mode='||BITAND(p1, POWER(2,14)-1)||']'
71+
WHEN a.event IN (SELECT name FROM v$event_name WHERE parameter3 = 'class#')
72+
THEN ' ['||CASE WHEN a.p3 <= (SELECT MAX(r) FROM bclass)
73+
THEN (SELECT class FROM bclass WHERE r = a.p3)
74+
ELSE (SELECT DECODE(MOD(BITAND(a.p3,TO_NUMBER('FFFF','XXXX')) - 17,2),0,'undo header',1,'undo data', 'error') FROM dual)
75+
END ||']'
76+
ELSE null
77+
END event2 -- event is NULL in ASH if the session is not waiting (session_state = ON CPU)
78+
, CASE WHEN a.session_type = 'BACKGROUND' OR REGEXP_LIKE(a.program, '.*\([PJ]\d+\)') THEN
79+
REGEXP_REPLACE(SUBSTR(a.program,INSTR(a.program,'(')), '\d', 'n')
80+
ELSE
81+
'('||REGEXP_REPLACE(REGEXP_REPLACE(a.program, '(.*)@(.*)(\(.*\))', '\1'), '\d', 'n')||')'
82+
END || ' ' program2
83+
FROM gv$active_session_history a) a
84+
, dba_users u
85+
, (SELECT
86+
object_id,data_object_id,owner,object_name,subobject_name,object_type
87+
, owner||'.'||object_name obj
88+
, owner||'.'||object_name||' ['||object_type||']' objt
89+
FROM dba_objects) o
90+
WHERE
91+
a.user_id = u.user_id (+)
92+
AND a.current_obj# = o.object_id(+)
93+
AND &2
94+
AND sample_time BETWEEN &3 AND &4
95+
GROUP BY
96+
&1
97+
ORDER BY
98+
TotalSeconds DESC
99+
, &1
100+
)
101+
WHERE
102+
ROWNUM <= 15
103+
/
104+

ash/asqlmon12.sql

Lines changed: 117 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,117 @@
1+
-- Copyright 2018 Tanel Poder. All rights reserved. More info at http://tanelpoder.com
2+
-- Licensed under the Apache License, Version 2.0. See LICENSE.txt for terms & conditions.
3+
4+
------------------------------------------------------------------------------------------------------------------------
5+
--
6+
-- File name: asqlmon.sql (v1.2)
7+
--
8+
-- Purpose: Report SQL-monitoring-style drill-down into where in an execution plan the execution time is spent
9+
--
10+
-- Author: Tanel Poder
11+
--
12+
-- Copyright: (c) https://tanelpoder.com - All rights reserved.
13+
--
14+
-- Disclaimer: This script is provided "as is", no warranties nor guarantees are
15+
-- made. Use at your own risk :)
16+
--
17+
-- Usage: @asqlmon <sqlid> <child#> <from_time> <to_time>
18+
--
19+
-- Notes: This script runs on Oracle 11g+ and you should have the
20+
-- Diagnostics pack license for using it as it queries
21+
-- some separately licensed views.
22+
--
23+
------------------------------------------------------------------------------------------------------------------------
24+
SET LINESIZE 999 PAGESIZE 5000 TRIMOUT ON TRIMSPOOL ON
25+
26+
COL asqlmon_operation HEAD Plan_Operation FOR a72
27+
COL asqlmon_predicates HEAD PREDICATES FOR a100 word_wrap
28+
COL obj_alias_qbc_name FOR a40
29+
COL options FOR a30
30+
31+
COL asqlmon_plan_hash_value HEAD PLAN_HASH_VALUE PRINT
32+
COL asqlmon_sql_id HEAD SQL_ID NOPRINT
33+
COL asqlmon_sql_child HEAD "CHILD" PRINT
34+
COL asqlmon_sample_time HEAD SAMPLE_HOUR
35+
COL projection FOR A520
36+
37+
COL pct_child HEAD "Activity %" FOR A8
38+
COL pct_child_vis HEAD "Visual" FOR A12
39+
40+
COL asqlmon_id HEAD "ID" FOR 9999
41+
COL asqlmon_parent_id HEAD "PID" FOR 9999
42+
43+
44+
BREAK ON asqlmon_sql_id SKIP 1 ON asqlmon_sql_child SKIP 1 ON asqlmon_plan_hash_value SKIP 1 ON asqlmon_sample_time SKIP 1 DUP ON asqlmon_operation
45+
46+
PROMPT
47+
PROMPT -- ASQLMon v1.1 - by Tanel Poder ( https://tanelpoder.com ) - Display SQL execution plan line level activity breakdown from ASH
48+
49+
WITH sample_times AS (
50+
select * from dual
51+
),
52+
sq AS (
53+
SELECT
54+
count(*) samples
55+
, ash.sql_id
56+
, ash.sql_child_number
57+
, ash.sql_plan_hash_value
58+
, ash.sql_full_plan_hash_value
59+
, NVL(ash.sql_plan_line_id,1) sql_plan_line_id -- this is because simple "planless" operations like single-row insert
60+
, ash.sql_plan_operation
61+
, ash.sql_plan_options
62+
, ash.session_state
63+
, ash.event
64+
-- , AVG(ash.p3) avg_p3 -- p3 is sometimes useful for listing block counts for IO wait events
65+
FROM
66+
v$active_session_history ash
67+
WHERE
68+
1=1
69+
AND ash.sql_id LIKE '&1'
70+
AND ash.sql_child_number LIKE '&2'
71+
AND ash.sample_time BETWEEN &3 AND &4
72+
GROUP BY
73+
ash.sql_id
74+
, ash.sql_child_number
75+
, ash.sql_plan_hash_value
76+
, ash.sql_full_plan_hash_value
77+
, NVL(ash.sql_plan_line_id,1)
78+
, ash.sql_plan_operation
79+
, ash.sql_plan_options
80+
, ash.session_state
81+
, ash.event
82+
)
83+
SELECT
84+
plan.sql_id asqlmon_sql_id
85+
, plan.child_number asqlmon_sql_child
86+
, plan.full_plan_hash_value asqlmon_full_plan_hash_value
87+
, plan.plan_hash_value asqlmon_plan_hash_value
88+
, sq.samples seconds
89+
, 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) pct_child
90+
, '|'||RPAD( NVL( LPAD('#', ROUND(RATIO_TO_REPORT(sq.samples) OVER (PARTITION BY sq.sql_id, sq.sql_plan_hash_value) * 10), '#'), ' '), 10,' ')||'|' pct_child_vis
91+
--, LPAD(plan.id,4)||CASE WHEN parent_id IS NULL THEN ' ' ELSE ' <- ' END||LPAD(plan.parent_id,4) asqlmon_plan_id
92+
, plan.id asqlmon_id
93+
, plan.parent_id asqlmon_parent_id
94+
, LPAD(' ', depth, ' ') || plan.operation ||' '|| plan.options || NVL2(plan.object_name, ' ['||plan.object_name ||']', null) asqlmon_operation
95+
, sq.session_state
96+
, sq.event
97+
-- , sq.avg_p3
98+
, plan.object_alias || CASE WHEN plan.qblock_name IS NOT NULL THEN ' ['|| plan.qblock_name || ']' END obj_alias_qbc_name
99+
-- , CASE WHEN plan.access_predicates IS NOT NULL THEN '[A:] '|| SUBSTR(plan.access_predicates,1,1990) END || CASE WHEN plan.filter_predicates IS NOT NULL THEN ' [F:] ' || SUBSTR(plan.filter_predicates,1,1990) END asqlmon_predicates
100+
-- , plan.projection
101+
FROM
102+
v$sql_plan plan
103+
, sq
104+
WHERE
105+
1=1
106+
AND sq.sql_id(+) = plan.sql_id
107+
AND sq.sql_child_number(+) = plan.child_number
108+
AND sq.sql_plan_line_id(+) = plan.id
109+
AND sq.sql_full_plan_hash_value(+) = plan.full_plan_hash_value
110+
--AND sq.sql_plan_hash_value(+) = plan.plan_hash_value
111+
AND plan.sql_id LIKE '&1'
112+
AND plan.child_number LIKE '&2'
113+
ORDER BY
114+
plan.child_number
115+
, plan.plan_hash_value
116+
, plan.id
117+
/

0 commit comments

Comments
 (0)