Skip to content

Commit

Permalink
Work fixes
Browse files Browse the repository at this point in the history
  • Loading branch information
xtender committed May 12, 2014
1 parent 86ff4db commit 6669d9d
Show file tree
Hide file tree
Showing 17 changed files with 235 additions and 60 deletions.
4 changes: 4 additions & 0 deletions ash/sessions_by_sqlid.sql
Expand Up @@ -8,6 +8,8 @@ col wait_class format a30;
col curobj format a30;
col module format a30;
col program format a15;
col ple format a45;
col plo format a45;
with ash_pre as (
select
h.inst_id
Expand Down Expand Up @@ -73,3 +75,5 @@ col wait_class clear;
col curobj clear;
col module clear;
col program clear;
col ple clear;
col plo clear;
81 changes: 81 additions & 0 deletions awr/sysstats_rows.sql
@@ -0,0 +1,81 @@
with v as (
select--+ leading(db sn st) use_nl(sn) use_nl(st) no_merge
st.snap_id
,sn.begin_interval_time as beg_time
,to_char(begin_interval_time,'fmday') as wd
,st.stat_name
,st.value - lag(value) over(partition by stat_name order by sn.snap_id) as value
,lag(sn.snap_id) over(partition by stat_name order by sn.snap_id) as prev_snap
from
v$database db
,dba_hist_snapshot sn
,dba_hist_sysstat st
where st.stat_name in (
'CPU used by this session'
,'user I/O wait time'
,'DB time'
-- ,'table scan rows gotten'
-- ,'rows fetched via callback'
-- ,'table fetch by rowid'
-- ,'table fetch continued row'
-- ,'index fetch by key'
)
and db.DBID = st.dbid
and st.snap_id = sn.snap_id
and sn.dbid = db.dbid
and sn.end_interval_time>trunc(sysdate)-365
)
,v2 as (
select snap_id,beg_time,wd,stat_name,value,prev_snap
,ntile(20) over(partition by stat_name order by value) nt
from v
where value > 0
and prev_snap + 1 = snap_id
and extract( hour from beg_time) in (10,11,12)
and wd not in ('saturday','sunday')
)
,v3 as (
select snap_id,beg_time,wd,stat_name,value,prev_snap
from v2
where snap_id not in ( select snap_id
from v2
group by snap_id
having sum(decode(nt,1,1,20,1))>=2
)
)
select
snap_id
,to_char(beg_time,'yyyy-mm-dd hh24:mi') beg_time
,wd
,to_char(cpu_time ,'fm999999999999') cpu_time
,to_char(io_time ,'fm999999999999') io_time
,to_char(db_time ,'fm999999999999') db_time
-- ,to_char(fts_rows ,'999g999g999999') fts_rows
-- ,to_char(fetches_callback ,'999g999g999999') fetches_callback
-- ,to_char(fetches_rowid ,'999g999g999999') fetches_rowid
-- ,to_char(fetches_continued ,'999g999g999999') fetches_continued
-- ,to_char(fetches_index_by_key ,'999g999g999999') fetches_index_by_key
,to_char(round(cpu_time *100/max(cpu_time )over(),2),'999.00') pct_cpu_time
,to_char(round(io_time *100/max(io_time )over(),2),'999.00') pct_io_time
,to_char(round(db_time *100/max(db_time )over(),2),'999.00') pct_db_time
-- ,to_char(round(fts_rows *100/max(fts_rows )over(),2),'999.00') pct_fts_rows
-- ,to_char(round(fetches_callback *100/max(fetches_callback )over(),2),'999.00') pct_fetches_callback
-- ,to_char(round(fetches_rowid *100/max(fetches_rowid )over(),2),'999.00') pct_fetches_rowid
-- ,to_char(round(fetches_continued *100/max(fetches_continued )over(),2),'999.00') pct_fetches_continued
-- ,to_char(round(fetches_index_by_key*100/max(fetches_index_by_key)over(),2),'999.00') pct_fetches_index_by_key
from v3
pivot(
max(value)
for stat_name in (
'CPU used by this session' cpu_time
,'user I/O wait time' io_time
,'DB time' db_time
-- ,'table scan rows gotten' fts_rows
-- ,'rows fetched via callback' fetches_callback
-- ,'table fetch by rowid' fetches_rowid
-- ,'table fetch continued row' fetches_continued
-- ,'index fetch by key' fetches_index_by_key
)
)
order by 1
/
49 changes: 33 additions & 16 deletions deps.sql
@@ -1,26 +1,43 @@
@inc/input_vars_init;

col OWNER format a30;
col NAME format a30;
col OBJECT_NAME format a50;
col TYPE format a12;
col REFERENCED_OWNER format a30 heading REF_OWNER;
col REFERENCED_NAME format a30 heading REF_NAME;
col REFERENCED_TYPE format a12 heading REF_TYPE;
col REFERENCED_LINK_NAME format a10 heading REF_LINK;
col REF_OWNER format a30 heading REF_OWNER;
col REF_NAME format a30 heading REF_NAME;
col REF_TYPE format a12 heading REF_TYPE;
col REF_LINK_NAME format a10 heading REF_LINK;
col DEPENDENCY_TYPE format a10;
break on ref_type on ref_owner on ref_name on object_name;

prompt Dependencies list:

select *
select
connect_by_root referenced_type as ref_type
,connect_by_root referenced_owner as ref_owner
,connect_by_root referenced_name as ref_name
,rpad(' ',level*2,'..')||dd.OWNER||'.'||dd.NAME as object_name
,dd.type
,(select o.CREATED from dba_objects o where o.OWNER = dd.OWNER and o.object_type = dd.type and o.object_name = dd.name) CREATED
,(select o.LAST_DDL_TIME from dba_objects o where o.OWNER = dd.OWNER and o.object_type = dd.type and o.object_name = dd.name) LAST_DDL_TIME
,(select o.status from dba_objects o where o.OWNER = dd.OWNER and o.object_type = dd.type and o.object_name = dd.name) obj_status
from dba_dependencies dd
where dd.referenced_owner like nvl(upper('&2'),'%')
and dd.referenced_name=upper('&1');
start with
dd.referenced_owner like nvl(upper('&2'),'%')
and dd.referenced_name = upper('&1')
and dd.referenced_link_name is null
connect by level<=3
and dd.referenced_owner = prior dd.OWNER
and dd.referenced_name = prior dd.NAME
and dd.REFERENCED_TYPE = prior dd.TYPE
and dd.REFERENCED_LINK_NAME is null
;

col OWNER clear;
col NAME clear;
col OBJECT_NAME clear;
col TYPE clear;
col REFERENCED_OWNER clear;
col REFERENCED_NAME clear;
col REFERENCED_TYPE clear;
col REFERENCED_LINK_NAME clear;
col REF_OWNER clear;
col REF_NAME clear;
col REF_TYPE clear;
col REF_LINK_NAME clear;
col DEPENDENCY_TYPE clear;

clear break;
@inc/input_vars_undef;
5 changes: 5 additions & 0 deletions expand_11.sql
@@ -0,0 +1,5 @@
var c clob
accept _query prompt "Enter query: ";
exec dbms_sql2.expand_sql_text(q'[&_query]',:c);
print :c;
undef _query;
1 change: 1 addition & 0 deletions inc/lateral_disable.sql
@@ -0,0 +1 @@
alter session set events '22829 trace name context off';
1 change: 1 addition & 0 deletions inc/lateral_enable.sql
@@ -0,0 +1 @@
alter session set events '22829 trace name context forever';
8 changes: 6 additions & 2 deletions obj.sql
Expand Up @@ -2,8 +2,12 @@
col owner format a30;
col object_name format a30;
col object_type format a25;
col last_ddl_time format a19;

select owner,object_name,object_type,object_id ,created,last_ddl_time,o.timestamp,status
select owner,object_name,object_type,object_id ,created
,to_char(last_ddl_time,'yyyy-mm-dd hh24:mi:ss') last_ddl_time
,o.timestamp
,status
from dba_objects o
where
(to_char(o.object_id) like '&1' or upper(object_name) like upper('&1'))
Expand All @@ -12,5 +16,5 @@ where
col owner clear;
col object_name clear;
col object_type clear;

col last_ddl_time clear;
@inc/input_vars_undef;
2 changes: 0 additions & 2 deletions rc/bypass.sql

This file was deleted.

2 changes: 2 additions & 0 deletions rc/bypass_off.sql
@@ -0,0 +1,2 @@
exec DBMS_RESULT_CACHE.BYPASS (false);
select DBMS_RESULT_CACHE.STATUS from dual;
2 changes: 2 additions & 0 deletions rc/bypass_on.sql
@@ -0,0 +1,2 @@
exec DBMS_RESULT_CACHE.BYPASS (true);
select DBMS_RESULT_CACHE.STATUS from dual;
2 changes: 2 additions & 0 deletions rc/status.sql
@@ -0,0 +1,2 @@
col "DBMS_RESULT_CACHE.STATUS" format a50;
select DBMS_RESULT_CACHE.STATUS "DBMS_RESULT_CACHE.STATUS" from dual;
4 changes: 3 additions & 1 deletion rtsm/execs.sql
@@ -1,4 +1,5 @@
@inc/input_vars_init
col SQL_EXEC_START format a19
col sid format 999999
col status format a30
col m_elaexe format a15 heading "Elapsed(MIN:SS)"
Expand All @@ -18,7 +19,7 @@ select
, SESSION_SERIAL# as serial#
, SQL_PLAN_HASH_VALUE as plan_hv
, SQL_EXEC_ID
, SQL_EXEC_START
, to_char(SQL_EXEC_START,'yyyy-mm-dd hh24:mi:ss') as SQL_EXEC_START

, to_char(trunc(ELAPSED_TIME/1e6/60))
||':'||
Expand Down Expand Up @@ -73,6 +74,7 @@ select *
from v
where rownum<=20;

col SQL_EXEC_START clear;
col status clear;
col m_elaexe clear;
col username clear;
Expand Down
37 changes: 0 additions & 37 deletions server/undo_used.sql

This file was deleted.

2 changes: 1 addition & 1 deletion sessions.sql
Expand Up @@ -22,7 +22,7 @@ select
,substr(s.program,1,20) program
,s.module
,s.terminal,s.type
&_IF_ORA11_OR_HIGHER ,s.SQL_EXEC_START
&_IF_ORA11_OR_HIGHER ,to_char(s.SQL_EXEC_START,'dd/mm hh24:mi:ss') sql_exec_start
,s.sql_id
,s.action
,s.event
Expand Down
2 changes: 1 addition & 1 deletion src.sql
Expand Up @@ -13,7 +13,7 @@ begin
,max(length(type))over() len_type
,max(length(text))over() len_text
from dba_source src
where src.owner like nvl('&2','%')
where src.owner like nvl(upper('&2'),'%')
and src.name like upper('&1')
)
loop
Expand Down
50 changes: 50 additions & 0 deletions tops/undo_used.sql
@@ -0,0 +1,50 @@
@inc/input_vars_init;
prompt *** Show top session by undo used:
prompt;
col username format a25;
col osuser format a25;
col process format a13;
col object format a40;
col subobject_name format a30;
col object_type format a20;
with t as (
select *
from (select *
from v$transaction
where used_ublk>0
order by used_ublk desc)
where rownum<=10
)
select
s.sid
,s.serial#
,s.username
,s.osuser
,t.used_urec as recs
,t.used_ublk as blocks
,o.owner||'.'||o.object_name object
,o.subobject_name
,o.data_object_id
,o.object_type
,l.object_id
,l.xidusn
,l.xidslot
,l.xidsqn
,l.process
from t
, v$session s
, v$locked_object l
, dba_objects o
where t.addr = s.taddr
and t.xidusn = l.xidusn(+)
and t.xidslot = l.xidslot(+)
and l.object_id = o.object_id(+)
order by blocks desc,sid
/
col username clear;
col osuser clear;
col process clear;
col object clear;
col subobject_name clear;
col object_type clear;
@inc/input_vars_undef;
43 changes: 43 additions & 0 deletions undo_used.sql
@@ -0,0 +1,43 @@
@inc/input_vars_init;
prompt *** Show undo used by SID.
prompt Usage: @undo_used sid

col username format a25;
col osuser format a25;
col process format a13;
col object format a40;
col subobject_name format a30;
col object_type format a20;
select
s.sid
,s.serial#
,s.username
,s.osuser
,t.used_urec as recs
,t.used_ublk as blocks
,o.owner||'.'||o.object_name object
,o.subobject_name
,o.data_object_id
,o.object_type
,l.object_id
,l.xidusn
,l.xidslot
,l.xidsqn
,l.process
from v$transaction t
, v$session s
, v$locked_object l
, dba_objects o
where t.addr = s.taddr
and t.xidusn = l.xidusn(+)
and t.xidslot = l.xidslot(+)
and l.object_id = o.object_id(+)
and sid = '&1'+0
/
col username clear;
col osuser clear;
col process clear;
col object clear;
col subobject_name clear;
col object_type clear;
@inc/input_vars_undef;

0 comments on commit 6669d9d

Please sign in to comment.