Skip to content

Commit

Permalink
First commit
Browse files Browse the repository at this point in the history
  • Loading branch information
Apress committed Oct 17, 2016
0 parents commit 372a030
Show file tree
Hide file tree
Showing 27 changed files with 520 additions and 0 deletions.
36 changes: 36 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_1.sql
@@ -0,0 +1,36 @@
DROP TABLE t_one;
CREATE TABLE t_one (n1 NUMBER , v1 VARCHAR2(100));
INSERT INTO t_one
SELECT n1, lpad (n1, 100,'DEADBEEF')
FROM
( SELECT level n1 FROM dual CONNECT BY level <=500
);
COMMIT;
CREATE INDEX t_one_n1 ON t_one (n1);
EXEC dbms_stats.gather_table_stats ( USER, 't_one', CASCADE =>true);

SELECT n1,
dbms_rowid.rowid_to_absolute_fno (rowid, 'RS','T_ONE') fno,
dbms_rowid.rowid_block_number(rowid) block,
dbms_rowid.rowid_object(rowid) obj,
LENGTH(v1) v1
FROM t_one
WHERE n1=100;

col res new_value resource_name

SELECT DISTINCT '[0x'||trim(TO_CHAR(dbms_rowid.rowid_block_number(rowid), 'xxxxxxxx'))
||'][0x'|| trim(TO_CHAR(dbms_rowid.rowid_to_absolute_fno (rowid,user,'T_ONE'),'xxxx'))
|| '],[BL]' res
FROM t_one
WHERE n1=100;

SELECT resource_name, ON_CONVERT_Q, ON_GRANT_Q, MASTER_NODE
FROM gv$ges_resource
WHERE resource_name LIKE '&resource_name%'
/
col state format a15
SELECT resource_name1, grant_level, state, owner_node
FROM v$ges_enqueue
WHERE resource_name1 LIKE '&resource_name%'
/
34 changes: 34 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_10.sql
@@ -0,0 +1,34 @@
col inst format 9999
col current_file# format 99999 head file
col current_block# format 9999999 head blk
WITH ash_gc AS
(SELECT * FROM
(SELECT /*+ materialize */ inst_id, event, current_obj#, current_file#,
current_block#, COUNT(*) cnt
FROM gv$active_session_history
WHERE event=lower('&event')
GROUP BY inst_id, event, current_obj#,
current_file#, current_block#
HAVING COUNT(*) >5
)
WHERE rownum <101
)
SELECT * FROM
(SELECT inst_id, owner, object_name, object_type, current_file#,
current_block#, cnt
FROM ash_gc a, dba_objects o
WHERE (a.current_obj# =o.object_id (+))
AND a.current_obj# >=1
UNION
SELECT inst_id, '', '', 'Undo Header/Undo block' ,
current_file#, current_block#, cnt
FROM ash_gc a
WHERE a.current_obj#=0
UNION
SELECT inst_id, '', '', 'Undo Block' ,
current_file#, current_block#, cnt
FROM ash_gc a
WHERE a.current_obj#=-1
)
ORDER BY 7 DESC
/
14 changes: 14 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_2.sql
@@ -0,0 +1,14 @@
set lines 120
col kjblname format a30
col kjblname2 format a20
col kjblgrant format a10
col kjblrole format 9999
col kjblrequest format A10
set verify off
select /*+ leading (c a b ) */ b.kjblname, b.kjblname2 ,
b.kjblgrant, b.kjblrole, b.kjblrequest , b.kjblmaster, b.kjblowner
from x$le a , x$kjbl b, x$bh c
where a.le_kjbl = b.kjbllockp
and a.le_addr =c.le_addr
and dbablk=&&block and obj=&&obj --and utl_raw.length(c.le_addr) >1
;
27 changes: 27 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_3.sql
@@ -0,0 +1,27 @@
col owner format a30
col object_name format a30
set lines 160
WITH ash_gc AS
(SELECT /*+ materialize */ inst_id, event, current_obj#, COUNT(*) cnt
FROM gv$active_session_history
WHERE event=lower('&event')
GROUP BY inst_id, event, current_obj#
HAVING COUNT (*) > &threshold )
SELECT * FROM
(SELECT inst_id, nvl( owner,'Non-existent') owner ,
nvl ( object_name,'Non-existent') object_name,
nvl ( object_type, 'Non-existent') object_type,
cnt, current_obj#
FROM ash_gc a, dba_objects o
WHERE (a.current_obj#=o.object_id (+))
AND a.current_obj# >=1
UNION
SELECT inst_id, '', '', 'Undo Header/Undo block', cnt, current_obj#
FROM ash_gc a WHERE a.current_obj#=0
UNION
SELECT inst_id, '', '', 'Undo Block', cnt, current_obj#
FROM ash_gc a
WHERE a.current_obj#=-1
)
ORDER BY cnt DESC
/
9 changes: 9 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_4.sql
@@ -0,0 +1,9 @@
WITH ash_gc AS
(SELECT /*+ materialize */ inst_id, event, sql_id, COUNT(*) cnt
FROM gv$active_session_history
WHERE event=lower('&event')
GROUP BY inst_id, event, sql_id
HAVING COUNT (*) > &threshold )
SELECT inst_id, sql_id, cnt FROM ash_gc
ORDER BY cnt DESC
/
17 changes: 17 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_5.sql
@@ -0,0 +1,17 @@
col event format a30
SELECT inst_id, event, wait_time_milli, wait_count,
TRUNC(100*(wait_count/tot),2) per
FROM
(SELECT inst_id, event, wait_time_milli, wait_count,
SUM (wait_count) over(partition BY inst_id, event
order by inst_id
rows BETWEEN unbounded preceding AND unbounded following
) tot
FROM
(SELECT * FROM gv$event_histogram
WHERE event LIKE '%&event_name%'
ORDER BY inst_id, event#, WAIT_TIME_MILLI
)
)
ORDER BY inst_id, event, WAIT_TIME_MILLI
/
19 changes: 19 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_6.sql
@@ -0,0 +1,19 @@
set lines 160
col begin_interval_time format a30
col event_name format a30
col instance_number format 99 head "Inst"
break on begin_interval_time
SELECT snaps.begin_interval_time,
snaps.instance_number,
hist.event_name,
hist.wait_time_milli,
hist.wait_count
FROM dba_hist_event_histogram hist, DBA_HIST_SNAPSHOT snaps
WHERE snaps.snap_id = hist.snap_id
AND snaps.instance_number = hist.instance_number
AND snaps.begin_interval_time > sysdate-1
AND hist.event_name = lower('&event_name')
ORDER BY snaps.snap_id ,
instance_number,
wait_time_milli
/
11 changes: 11 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_7.sql
@@ -0,0 +1,11 @@
SELECT instance ||'->' || inst_id transfer,
class,
cr_block cr_blk,
TRUNC(cr_block_time /cr_block/1000,2) avg_Cr,
current_block cur_blk,
TRUNC(current_block_time/current_block/1000,2) avg_cur
FROM gv$instance_cache_transfer
WHERE cr_block >0 AND current_block>0
ORDER BY instance, inst_id, class
/

11 changes: 11 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_8.sql
@@ -0,0 +1,11 @@
SELECT
DECODE(state,0,'free',1,'xcur',2,'scur',3,'cr', 4,'read',5,'mrec',
6,'irec',7,'write',8,'pi', 9,'memory',10,'mwrite',
11,'donated', 12,'protected', 13,'securefile', 14,'siop',
15,'recckpt', 16, 'flashfree', 17, 'flashcur', 18, 'flashna') state,
mode_held, le_addr, dbarfil, dbablk, cr_scn_bas, cr_scn_wrp , class
FROM sys.x$bh
WHERE obj= &&obj
AND dbablk= &&block
AND state!=0 ;

13 changes: 13 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/Listing_10_9.sql
@@ -0,0 +1,13 @@
SELECT inst_id,
TRUNC(data_requests /tot_req,2) * 100 data_per,
TRUNC(undo_requests /tot_req,2) * 100 undo_per,
TRUNC(tx_requests /tot_req,2) * 100 tx_per,
TRUNC(other_requests/tot_req,2) * 100 other_per
FROM
(SELECT inst_id, cr_Requests + current_Requests tot_req,
data_requests, undo_requests, tx_requests, other_requests
FROM gv$cr_block_server
)
ORDER BY inst_id
/

7 changes: 7 additions & 0 deletions 978-1-4302-5044-9/ch10/listings_10/tc_one_row.sql
@@ -0,0 +1,7 @@
set lines 120
select n1,
dbms_rowid.rowid_relative_fno (rowid) fno,
dbms_rowid.rowid_block_number(rowid) block,
dbms_rowid.rowid_object(rowid) obj,
v1
from rs.t_one where n1=100;
19 changes: 19 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_1.sql
@@ -0,0 +1,19 @@
select
to_date(to_char(trunc(begin_interval_time), 'DD-MON-YYYY'), 'DD-MON-YYYY') DAY,
instance_number,
trunc(max(bytes/1024/1024),2) sz_MB
from
(select begin_interval_time, s.instance_number, sum(bytes) bytes
from
dba_hist_sgastat g, dba_hist_snapshot s
where (name like '%ges%' or name like '%gcs%')
and trunc(begin_interval_time) >= sysdate -30
and s.snap_id = g.snap_id
and s.instance_number = g.instance_number
group by begin_interval_time, s.instance_number
)
group by
to_date(to_char(trunc(begin_interval_time), 'DD-MON-YYYY'), 'DD-MON-YYYY'),
instance_number
order by 1
/
37 changes: 37 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_10.sql
@@ -0,0 +1,37 @@
REM Derive a resource_name string from object_id
col res new_value resource_name
col master_node head 'Mast|node' format 99
col value_blk format a30
declare
begin
for c1 in (
SELECT DISTINCT '[0x'
||trim(TO_CHAR(13, 'xxxxxxxx'))
||']'
|| '%'
|| '],[CI]%' res
FROM dual
)
loop
-- Using the derived resource_name, identify all GES resources
for c2 in(
SELECT distinct inst_id, resource_name, master_node, value_blk, value_blk_state
FROM gv$ges_resource WHERE resource_name LIKE c1.res
)
loop
dbms_output.put_line ('Resource name '|| c2.resource_name || ', Master '||c2.master_node ||',Instance '|| c2.inst_id);
dbms_output.put_line ('...Value '|| c2.value_blk || ' State:'|| c2.value_blk_state);
end loop;
dbms_output.put_line ('-------------------');
dbms_output.put_line ('Lock details...');
dbms_output.put_line ('-------------------');
for c2 in ( select distinct inst_id, resource_name1, transaction_id0, pid,
state, owner_node , grant_level , request_level from gv$ges_enqueue
where resource_name1 like c1.res)
loop
dbms_output.put_line ('Res name '|| c2.resource_name1 || ', owner '||c2.owner_node );
dbms_output.put_line ('...Transaction_id0 '|| c2.transaction_id0 ||',Gr. lvl '||c2.grant_level|| ', Req Lvl '|| c2.request_level ||',State ' || c2.state );
end loop;
end loop;
end;
/
19 changes: 19 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_11.sql
@@ -0,0 +1,19 @@
REM create a table
CREATE TABLE t_libtest (n1 NUMBER );

REM dynamically populate a CLOB variable and try to parse it.
DECLARE
v_sqltext CLOB;
c1 NUMBER ;
BEGIN
v_sqltext:= ' select a0.* from t_libtest a0';
c1 := dbms_sql.open_cursor;
FOR i IN 1 .. 1024
LOOP
v_sqltext := v_sqltext ||' , t_libtest a'||i;
END LOOP;
dbms_output.put_line(v_sqltext);
dbms_sql.parse( c1, v_sqltext, dbms_sql.native);
END;
/

33 changes: 33 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_12.sql
@@ -0,0 +1,33 @@
set serveroutput on size 1000000
declare
begin
for c1 in (
select
'[0x'|| substr(kglnahsv, 1,8) || '][0x'|| substr(kglnahsv, 9, 8) || ']' res,
kglnaown owner, kglnaobj objname
from x$kglob where kglnaobj like upper('&objname')
)
loop
dbms_output.put_line ('-------------------');
dbms_output.put_line ('Object Details...' || c1.owner||'.'|| c1.objname);
dbms_output.put_line ('-------------------');
dbms_output.put_line ('-------------------');
dbms_output.put_line ('Resource details...');
dbms_output.put_line ('-------------------');
for c2 in ( select resource_name, master_node from v$ges_resource
where resource_name like '%'||c1.res||'%')
loop
dbms_output.put_line ('Resource name '|| c2.resource_name || ', Master '||c2.master_node );
end loop;
dbms_output.put_line ('-------------------');
dbms_output.put_line ('Lock details...');
dbms_output.put_line ('-------------------');
for c2 in ( select resource_name1, transaction_id0, pid, state, owner_node , grant_level from v$ges_enqueue
where resource_name1 like '%'||c1.res||'%')
loop
dbms_output.put_line ('Res name '|| c2.resource_name1 || ', owner '||c2.owner_node );
dbms_output.put_line ('...Transaction_id0 '|| c2.transaction_id0 ||',Level '||c2.grant_level|| ',State ' || c2.state );
end loop;
end loop;
end;
/
23 changes: 23 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_2.sql
@@ -0,0 +1,23 @@
REM First let us lock a small table in exclusive mode
REM SQL #1
LOCK TABLE t1 IN exclusive MODE;
REM Query gv$lock to review single instance locks.
REM SQL #2
SELECT sid, type, id1, id2, lmode, request FROM gv$lock WHERE type='TM';

REM Global resource is created with an unique resource name referring to
REM object_id of the table.

REM SQL #3
SELECT inst_id, resource_name, master_node, on_convert_q, on_grant_q
FROM gv$ges_resource WHERE resource_name LIKE '[0xb6dff3]%TM%' ;

REM Locks are acquired on that global resource in an Exclusive mode.
REM SQL #4
BEGIN
print_Table (q'#
select inst_id, resource_name1, grant_level, request_level,state, blocked, blocker from
gv$ges_enqueue where resource_name1 like '[0xb6dff3]%TM%'
#');
END;
/
6 changes: 6 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_3.sql
@@ -0,0 +1,6 @@
col inst_id format 99
col owner_node format 99 head 'Owner|Node'

SELECT inst_id, pid, resource_name1, state, owner_node, blocked, blocker
FROM gv$ges_blocking_enqueue
ORDER BY resource_name1;
23 changes: 23 additions & 0 deletions 978-1-4302-5044-9/ch11/scripts_ch11/listing_11_4.sql
@@ -0,0 +1,23 @@
col state format A10
col pid format 99999999
begin
backup.print_Table ('
with dl as (
SELECT inst_id, resource_name1, grant_level, request_level,
transaction_id0, which_queue, state, pid, blocked ,
blocker
FROM gv$ges_blocking_enqueue
WHERE transaction_id0!=0 )
SELECT dl.inst_id, dl.resource_name1, dl.grant_level,
dl.request_level, dl.state, s.sid, sw.event,
sw.seconds_in_wait sec
FROM dl,
gv$process p, gv$session s, gv$session_wait sw
WHERE (dl.inst_id = p.inst_id AND dl.pid = p.spid)
AND (p.inst_id = s.inst_id AND p.addr = s.paddr)
AND (s.inst_id = sw.inst_id AND s.sid = sw.sid)
ORDER BY sw.seconds_in_wait DESC
');
end;
/

0 comments on commit 372a030

Please sign in to comment.