├── 9781430239543.jpg ├── LICENSE.txt ├── README.md ├── ch_02 ├── c_dump_log.sql ├── c_dump_seg.sql ├── c_dump_undo_block.sql ├── c_mystats.sql ├── core_demo_02.sql ├── core_demo_02b.sql ├── core_imu_01.sql ├── setenv.sql ├── snap_11_latch.sql ├── snap_9_latch.sql ├── snap_9_latch_child.sql ├── snap_9_latch_parent.sql ├── snap_myst.sql └── snap_stat.sql ├── ch_03 ├── c_dump_seg.sql ├── c_dump_tab.sql ├── c_mystats.sql ├── cleanout.sql ├── core_03_ct.sql ├── core_cleanout.sql ├── core_cleanout_2.sql ├── core_cleanout_3.sql ├── core_cleanout_4.sql ├── setenv.sql ├── snap_11_kcbsw.sql ├── snap_9_buffer.sql ├── snap_9_kcbsw.sql ├── snap_myst.sql ├── snap_rollstat.sql └── snap_stat.sql ├── ch_06 ├── c_mystats.sql ├── core_commit_01.sql ├── setenv.sql ├── snap_11_sysev.sql ├── snap_9_latch.sql ├── snap_events.sql ├── snap_my_redo.sql ├── snap_myst.sql ├── snap_redo.sql └── snap_sysev.sql ├── ch_07 ├── c_mystats.sql ├── core_dc_activity_01.sql ├── core_dc_activity_02.sql ├── core_dc_activity_03.sql ├── core_dc_activity_04.sql ├── core_dc_activity_05.sql ├── setenv.sql ├── snap_11_latch.sql ├── snap_9_latch.sql ├── snap_9_latch_child.sql ├── snap_myst.sql └── snap_rowcache.sql └── contributing.md /9781430239543.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Apress/oracle-core-esntl-internals-for-dbas-devs/7fac9deb8954d19fa6b55ba2ba1a9508fa584341/9781430239543.jpg -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Apress/oracle-core-esntl-internals-for-dbas-devs/7fac9deb8954d19fa6b55ba2ba1a9508fa584341/LICENSE.txt -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Apress Source Code 2 | 3 | This repository accompanies [*Oracle Core: Essential Internals for DBAs and Developers*](http://www.apress.com/9781430239543) by Jonathan Lewis (Apress, 2011). 4 | 5 | ![Cover image](9781430239543.jpg) 6 | 7 | Download the files as a zip using the green button, or clone the repository to your machine using Git. 8 | 9 | ## Releases 10 | 11 | Release v1.0 corresponds to the code in the published book, without corrections or updates. 12 | 13 | ## Contributions 14 | 15 | See the file Contributing.md for more information on how you can contribute to this repository. 16 | -------------------------------------------------------------------------------- /ch_02/c_dump_log.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_dump_log.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: December 2002 5 | rem Purpose: Dump the current online redo log file. 6 | rem 7 | rem 8 | rem Last tested 9 | rem 11.2.0.2 10 | rem 10.2.0.3 11 | rem 10.1.0.4 12 | rem 9.2.0.8 13 | rem 8.1.7.4 14 | rem 15 | rem Notes: 16 | rem Must be run as a DBA 17 | rem Very simple minded - no error trapping 18 | rem 19 | 20 | start setenv 21 | 22 | create or replace procedure dump_log 23 | as 24 | m_log_name varchar2(255); 25 | m_process varchar2(32); 26 | 27 | begin 28 | select 29 | lf.member 30 | into 31 | m_log_name 32 | from 33 | V$log lo, 34 | v$logfile lf 35 | where 36 | lo.status = 'CURRENT' 37 | and lf.group# = lo.group# 38 | and rownum = 1 39 | ; 40 | 41 | execute immediate 42 | 'alter system dump logfile ''' || m_log_name || ''''; 43 | 44 | select 45 | spid 46 | into 47 | m_process 48 | from 49 | v$session se, 50 | v$process pr 51 | where 52 | se.sid = --dbms_support.mysid 53 | (select sid from v$mystat where rownum = 1) 54 | and pr.addr = se.paddr 55 | ; 56 | 57 | dbms_output.put_line('Trace file name includes: ' || m_process); 58 | 59 | end; 60 | . 61 | / 62 | 63 | show errors 64 | 65 | create public synonym dump_log for dump_log; 66 | grant execute on dump_log to public; 67 | 68 | spool off 69 | 70 | 71 | set doc off 72 | doc 73 | 74 | ---------------------------------------------- 75 | 76 | Skipping IMU Redo Record: cannot be filtered by XID/OBJNO 77 | ------------------------------------------------- 78 | ---------------------------------------------- 79 | 80 | Skipping IMU Redo Record: cannot be filtered by XID/OBJNO 81 | ------------------------------------------------- 82 | ---------------------------------------------- 83 | 84 | Skipping IMU Redo Record: cannot be filtered by XID/OBJNO 85 | ------------------------------------------------- 86 | ---------------------------------------------- 87 | 88 | Skipping IMU Redo Record: cannot be filtered by XID/OBJNO 89 | ------------------------------------------------- 90 | 91 | # 92 | -------------------------------------------------------------------------------- /ch_02/c_dump_seg.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_dump_seg.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: December 2002 5 | rem Purpose: Create a procedure to dump blocks from a segment 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 11.1.0.7 10 | rem 10.2.0.3 11 | rem 10.1.0.4 12 | rem 9.2.0.6 13 | rem 8.1.7.4 14 | rem 15 | rem Notes: 16 | rem The code is very simple minded with no error trapping. 17 | rem It only covers the first extent (extent zero) of a segment 18 | rem Could be enhanced to use get_ev to save and restore the state 19 | rem of event 10289 (the one that controls raw/cooked dumps). 20 | rem 21 | rem Change in 10.2: the raw block dump always appears in 22 | rem a block dump, you cannot stop it. Event 10289 blocks 23 | rem the appearance of the formatted dump 24 | rem 25 | rem Script has to be run by a DBA who has the privileges to 26 | rem view v$process, v$session, v$mystat 27 | rem 28 | rem Usage 29 | rem -- the notes assume the tablespace is not ASSM. 30 | rem execute dump_seg('tablex'); -- dump first data block 31 | rem execute dump_seg('tablex',5) -- dump first five data blocks 32 | rem execute dump_seg('indexy',1,'INDEX') -- dump root block of index 33 | rem execute dump_seg('tableX',i_start_block=>0 ) -- dump seg header block 34 | rem 35 | rem Various "optimizer" issues with 10g: 36 | rem select * from dba_extents 37 | rem where segment_name = 'T1' 38 | rem and extent_id = 0; 39 | rem vs. 40 | rem select * from dba_extents 41 | rem where segment_name = 'T1' 42 | rem order by extent_id; 43 | rem 44 | rem On one system, the first query crashed with error: 45 | rem ORA-00379: no free buffers available in buffer pool DEFAULT for block size 2K 46 | rem 47 | rem There had been an object in the 2K tablespace, 48 | rem which had been dropped but not purged. There 49 | rem were no buffers allocated to the 2K cache, 50 | rem hence the failure. And it was not possible 51 | rem to purge the recyclebin without creating the 52 | rem cache. 53 | rem 54 | rem Clearly, the join order had changed because of 55 | rem the extent_id predicate - and this led to the 56 | rem crash 57 | rem 58 | rem For this reason, I changed the code to query by 59 | rem segment and order by extent_id - stopping at the 60 | rem zero extent 61 | rem 62 | rem Performance can also be affected by how many extents 63 | rem you have, and whether you have collected statistics 64 | rem (in 10g) on the fixed tables - because of the call to 65 | rem check the extents in the segment headers. 66 | rem 67 | rem Internal enhancements in 11g 68 | rem You get a dump of all the copies in the buffer cache, 69 | rem and a copy of the version of the block on disc. 70 | rem 71 | 72 | start setenv 73 | 74 | create or replace procedure dump_seg( 75 | i_seg_name in varchar2, 76 | i_block_count in number default 1, 77 | i_seg_type in varchar2 default 'TABLE', 78 | i_start_block in number default 1, 79 | i_owner in varchar2 default sys_context('userenv','session_user'), 80 | i_partition_name in varchar2 default null, 81 | i_dump_formatted in boolean default true, 82 | i_dump_raw in boolean default false 83 | ) 84 | as 85 | m_file_id number; 86 | m_block_min number; 87 | m_block_max number; 88 | m_process varchar2(32); 89 | 90 | begin 91 | 92 | for r in ( 93 | select 94 | file_id, 95 | block_id + i_start_block block_min, 96 | block_id + i_start_block + i_block_count - 1 block_max 97 | from 98 | dba_extents 99 | where 100 | segment_name = upper(i_seg_name) 101 | and segment_type = upper(i_seg_type) 102 | and owner = upper(i_owner) 103 | and nvl(partition_name,'N/A') = upper(nvl(i_partition_name,'N/A')) 104 | order by 105 | extent_id 106 | ) loop 107 | 108 | m_file_id := r.file_id; 109 | m_block_min := r.block_min; 110 | m_block_max := r.block_max; 111 | exit; 112 | end loop; 113 | 114 | if (i_dump_formatted) then 115 | execute immediate 116 | 'alter session set events ''10289 trace name context off'''; 117 | 118 | execute immediate 119 | 'alter system dump datafile ' || m_file_id || 120 | ' block min ' || m_block_min || 121 | ' block max ' || m_block_max 122 | ; 123 | end if; 124 | 125 | if (i_dump_raw) then 126 | execute immediate 127 | 'alter session set events ''10289 trace name context forever'''; 128 | 129 | execute immediate 130 | 'alter system dump datafile ' || m_file_id || 131 | ' block min ' || m_block_min || 132 | ' block max ' || m_block_max 133 | ; 134 | 135 | end if; 136 | 137 | execute immediate 138 | 'alter session set events ''10289 trace name context off'''; 139 | 140 | -- 141 | -- For non-MTS, work out the trace file name 142 | -- 143 | 144 | select 145 | spid 146 | into 147 | m_process 148 | from 149 | v$session se, 150 | v$process pr 151 | where 152 | se.sid = (select sid from v$mystat where rownum = 1) 153 | and pr.addr = se.paddr 154 | ; 155 | 156 | dbms_output.new_line; 157 | dbms_output.put_line( 158 | 'Dumped ' || i_block_count || ' blocks from ' || 159 | i_seg_type || ' ' || i_seg_name || 160 | ' starting from block ' || i_start_block 161 | ); 162 | 163 | dbms_output.new_line; 164 | dbms_output.put_line('Trace file name includes: ' || m_process); 165 | 166 | dbms_output.new_line; 167 | 168 | exception 169 | when others then 170 | dbms_output.new_line; 171 | dbms_output.put_line('Unspecified error.'); 172 | dbms_output.put_line('Check syntax.'); 173 | dbms_output.put_line('dumpseg({segment_name},[{block count}],[{segment_type}]'); 174 | dbms_output.put_line(' [{start block (1)}],[{owner}],[{partition name}]'); 175 | dbms_output.put_line(' [{dump formatted YES/n}],[{dump raw y/NO}]'); 176 | dbms_output.new_line; 177 | raise; 178 | end; 179 | . 180 | / 181 | 182 | show errors 183 | 184 | drop public synonym dump_seg; 185 | create public synonym dump_seg for dump_seg; 186 | grant execute on dump_seg to public; 187 | -------------------------------------------------------------------------------- /ch_02/c_dump_undo_block.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_dump_undo_block.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: December 2002 5 | rem Purpose: Create a procedure to dump your CURRENT undo block 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 11.1.0.7 10 | rem 10.2.0.3 11 | rem 9.2.0.8 12 | rem Not tested 13 | rem 10.1.0.4 14 | rem 8.1.7.4 15 | rem 16 | rem Notes: 17 | rem The code is very simple minded with no error trapping. 18 | rem Has to be run by SYS to create the procedure. 19 | rem 20 | 21 | start setenv 22 | 23 | 24 | create or replace procedure dump_undo_block 25 | as 26 | m_xidusn number; 27 | m_header_file_id number; 28 | m_header_block_id number; 29 | m_start_file_id number; 30 | m_start_block_id number; 31 | m_file_id number; 32 | m_block_id number; 33 | m_process number; 34 | begin 35 | 36 | select 37 | xidusn, 38 | start_ubafil, 39 | start_ubablk, 40 | ubafil, 41 | ubablk 42 | into 43 | m_xidusn, 44 | m_start_file_id, 45 | m_start_block_id, 46 | m_file_id, 47 | m_block_id 48 | from 49 | v$session ses, 50 | v$transaction trx 51 | where 52 | ses.sid = (select mys.sid from V$mystat mys where rownum = 1) 53 | and trx.ses_addr = ses.saddr 54 | ; 55 | 56 | select 57 | file_id, block_id 58 | into 59 | m_header_file_id, 60 | m_header_block_id 61 | from 62 | dba_rollback_segs 63 | where 64 | segment_id = m_xidusn 65 | ; 66 | 67 | 68 | dbms_output.put_line('Header File: ' || m_header_file_id || ' Header block: ' || m_header_block_id); 69 | dbms_output.put_line('Start File: ' || m_start_file_id || ' Start block: ' || m_start_block_id); 70 | dbms_output.put_line('Current File: ' || m_file_id || ' Current block: ' || m_block_id); 71 | 72 | 73 | dbms_system.ksdwrt(1,'==================='); 74 | dbms_system.ksdwrt(1,'Undo Segment Header'); 75 | dbms_system.ksdwrt(1,'==================='); 76 | 77 | execute immediate 78 | 'alter system dump datafile ' || m_header_file_id ||' block ' || m_header_block_id; 79 | 80 | dbms_system.ksdwrt(1,'================'); 81 | dbms_system.ksdwrt(1,'Undo Start block'); 82 | dbms_system.ksdwrt(1,'================'); 83 | 84 | execute immediate 85 | 'alter system dump datafile ' || m_start_file_id ||' block ' || m_start_block_id; 86 | 87 | if m_start_block_id != m_block_id then 88 | 89 | dbms_system.ksdwrt(1,'=================='); 90 | dbms_system.ksdwrt(1,'Current Undo block'); 91 | dbms_system.ksdwrt(1,'=================='); 92 | 93 | execute immediate 94 | 'alter system dump datafile ' || m_file_id ||' block ' || m_block_id; 95 | 96 | end if; 97 | 98 | select 99 | spid 100 | into 101 | m_process 102 | from 103 | v$session se, 104 | v$process pr 105 | where se.sid = (select sid from v$mystat where rownum = 1) 106 | and 107 | pr.addr = se.paddr 108 | ; 109 | 110 | dbms_output.put_line('Trace file name includes: ' || m_process); 111 | 112 | end; 113 | / 114 | 115 | grant execute on dump_undo_block to public; 116 | 117 | drop public synonym dump_undo_block; 118 | create public synonym dump_undo_block for dump_undo_block; 119 | 120 | 121 | set doc off 122 | doc 123 | 124 | 125 | # 126 | -------------------------------------------------------------------------------- /ch_02/c_mystats.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_mystats.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Put names to v$mystat 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 10.2.0.3 10 | rem 10.1.0.4 11 | rem 9.2.0.8 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Should be run by SYS - which means it has to be re-run 16 | rem on a full database export/import 17 | 18 | rem 19 | rem Option 1 - using v$ 20 | rem Use first_rows and ordered to avoid a sort/merge join, and 21 | rem to allow faster elimination of the 'value = 0' rows. 22 | rem 23 | 24 | create or replace view v$my_stats 25 | as 26 | select 27 | /*+ 28 | first_rows 29 | ordered 30 | */ 31 | ms.sid, 32 | sn.statistic#, 33 | sn.name, 34 | sn.class, 35 | ms.value 36 | from 37 | v$mystat ms, 38 | v$statname sn 39 | where 40 | sn.statistic# = ms.statistic# 41 | ; 42 | 43 | rem 44 | rem Option 2 - using x$ 45 | rem Avoids the filter subquery for count(*) from x$ksusd 46 | rem (See v$fixed_view_definition) 47 | rem 48 | 49 | create or replace view v$my_stats 50 | as 51 | select 52 | /*+ 53 | first_rows 54 | ordered 55 | */ 56 | ms.ksusenum sid, 57 | sn.indx statistic#, 58 | sn.ksusdnam name, 59 | sn.ksusdcls class, 60 | ms.ksusestv value 61 | from 62 | x$ksumysta ms, 63 | x$ksusd sn 64 | where 65 | ms.inst_id = sys_context('userenv','instance') 66 | and bitand(ms.ksspaflg,1)!=0 67 | and bitand(ms.ksuseflg,1)!=0 68 | and sn.inst_id = sys_context('userenv','instance') 69 | and sn.indx = ms.ksusestn 70 | ; 71 | 72 | drop public synonym v$my_stats; 73 | create public synonym v$my_stats for v$my_stats; 74 | grant select on v$my_stats to public; 75 | -------------------------------------------------------------------------------- /ch_02/core_demo_02b.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_demo_02b.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: Feb 2011 5 | rem Purpose: 6 | rem 7 | rem Last tested 8 | rem 10.2.0.3 9 | rem 9.2.0.8 10 | rem Not tested 11 | rem 11.2.0.2 12 | rem 11.1.0.7 13 | rem Not considered 14 | rem 8.1.7.4 15 | rem 16 | rem Notes: 17 | rem As for core_demo_02.sql, but used to show the 18 | rem number of redo entries and latch gets. We update 19 | rem 50 rows to make the difference more visible. 20 | rem 21 | rem Depends on 22 | rem c_mystats.sql 23 | rem snap_myst.sql 24 | rem snap_stat.sql 25 | rem snap_9_latch.sql (snap_11_latch.sql) 26 | rem snap_9_latch_child.sql 27 | rem 28 | 29 | start setenv 30 | set timing off 31 | 32 | execute dbms_random.seed(0) 33 | 34 | drop table t1; 35 | 36 | begin 37 | begin execute immediate 'purge recyclebin'; 38 | exception when others then null; 39 | end; 40 | 41 | begin 42 | dbms_stats.set_system_stats('MBRC',8); 43 | dbms_stats.set_system_stats('MREADTIM',26); 44 | dbms_stats.set_system_stats('SREADTIM',12); 45 | dbms_stats.set_system_stats('CPUSPEED',800); 46 | exception 47 | when others then null; 48 | end; 49 | 50 | begin execute immediate 'begin dbms_stats.delete_system_stats; end;'; 51 | exception when others then null; 52 | end; 53 | 54 | begin execute immediate 'alter session set "_optimizer_cost_model"=io'; 55 | exception when others then null; 56 | end; 57 | end; 58 | / 59 | 60 | 61 | create table t1 62 | as 63 | select 64 | 2 * rownum - 1 id, 65 | rownum n1, 66 | cast('xxxxxx' as varchar2(10)) v1, 67 | rpad('0',100,'0') padding 68 | from 69 | all_objects 70 | where 71 | rownum <= 60 72 | union all 73 | select 74 | 2 * rownum id, 75 | rownum n1, 76 | cast('xxxxxx' as varchar2(10)) v1, 77 | rpad('0',100,'0') padding 78 | from 79 | all_objects 80 | where 81 | rownum <= 60 82 | ; 83 | 84 | create index t1_i1 on t1(id); 85 | 86 | begin 87 | dbms_stats.gather_table_stats( 88 | ownname => user, 89 | tabname =>'T1', 90 | method_opt => 'for all columns size 1' 91 | ); 92 | end; 93 | / 94 | 95 | 96 | select 97 | dbms_rowid.rowid_block_number(rowid) block_number, 98 | count(*) rows_per_block 99 | from 100 | t1 101 | group by 102 | dbms_rowid.rowid_block_number(rowid) 103 | order by 104 | block_number 105 | ; 106 | 107 | 108 | alter system switch logfile; 109 | execute dbms_lock.sleep(2) 110 | 111 | spool core_demo_02b.lst 112 | 113 | execute snap_my_stats.start_snap 114 | execute snap_stats.start_snap 115 | execute snap_latch.start_snap 116 | execute snap_latch_child.start_snap('redo copy') 117 | -- execute snap_latch_child.start_snap('redo allocation') 118 | -- execute snap_latch_child.start_snap('In memory undo latch') 119 | 120 | update 121 | /*+ index(t1 t1_i1) */ 122 | t1 123 | set 124 | v1 = 'YYYYYYYYYY' 125 | where 126 | id between 5 and 54 127 | ; 128 | 129 | -- 130 | -- There is an important difference in results between 131 | -- taking the snapshot before or after the commit. 132 | -- 133 | -- My code only allows for reporting one child latch 134 | -- 135 | 136 | -- execute snap_latch_child.end_snap('In memory undo latch') 137 | -- execute snap_latch_child.end_snap('redo allocation') 138 | execute snap_latch_child.end_snap('redo copy') 139 | execute snap_latch.end_snap 140 | execute snap_stats.end_snap 141 | execute snap_my_stats.end_snap 142 | 143 | commit; 144 | 145 | -- execute snap_latch_child.end_snap('In memory undo latch') 146 | -- execute snap_latch_child.end_snap('redo allocation') 147 | execute snap_latch_child.end_snap('redo copy') 148 | execute snap_latch.end_snap 149 | execute snap_stats.end_snap 150 | execute snap_my_stats.end_snap 151 | 152 | 153 | spool off 154 | 155 | 156 | set doc off 157 | doc 158 | 159 | 9.2.0.8 160 | ======= 161 | Latch Gets Misses Sp_Get Sleeps Im_Gets Im_Miss Holding Woken Time ms 162 | ----- ---- ------ ------ ------ ------- ------- ------- ----- ------- 163 | redo copy 0 0 0 0 51 0 0 0 .0 164 | redo allocation 53 0 0 0 0 0 0 0 .0 165 | 166 | redo writing 3 0 0 0 0 0 0 0 .0 167 | undo global data 3 0 0 0 0 0 0 0 .0 168 | cache buffers chains 267 0 0 0 1 0 0 0 .0 169 | 170 | --------------------------------- 171 | System stats:- 05-Apr 16:03:14 172 | Interval:- 0 seconds 173 | --------------------------------- 174 | Name Value 175 | ---- ----- 176 | redo synch writes 1 177 | redo entries 51 178 | redo size 12,668 179 | redo wastage 228 180 | redo writes 1 181 | redo blocks written 26 182 | 183 | --------------------------------- 184 | Session stats - 05-Apr 16:03:14 185 | Interval:- 0 seconds 186 | --------------------------------- 187 | Name Value 188 | ---- ----- 189 | session logical reads 56 190 | db block gets 54 191 | consistent gets 2 192 | db block changes 103 193 | redo entries 51 194 | redo size 12,668 195 | 196 | 197 | 198 | 10.2.0.3 199 | ======== 200 | 201 | --------------------------------- 202 | Latch waits:- 05-Apr 16:09:11 203 | Interval:- 0 seconds 204 | --------------------------------- 205 | Latch Gets Misses Sp_Get Sleeps Im_Gets Im_Miss Holding Woken Time ms 206 | ----- ---- ------ ------ ------ ------- ------- ------- ----- ------- 207 | redo writing 3 0 0 0 0 0 0 0 .0 208 | redo copy 0 0 0 0 1 0 0 0 .0 209 | redo allocation 5 0 0 0 1 0 0 0 .0 210 | undo global data 5 0 0 0 0 0 0 0 .0 211 | In memory undo latch 53 0 0 0 1 0 0 0 .0 212 | cache buffers chains 379 0 0 0 0 0 0 0 .0 213 | 214 | 215 | --------------------------------- 216 | System stats:- 05-Apr 16:09:11 217 | Interval:- 0 seconds 218 | --------------------------------- 219 | Name Value 220 | ---- ----- 221 | redo synch writes 1 222 | redo synch time 1 223 | redo entries 1 224 | redo size 12,048 225 | redo wastage 352 226 | 227 | redo writes 1 228 | redo blocks written 25 229 | 230 | undo change vector size 4,632 231 | IMU commits 1 232 | IMU undo allocation size 43,052 233 | 234 | --------------------------------- 235 | Session stats - 05-Apr 16:09:11 236 | Interval:- 0 seconds 237 | --------------------------------- 238 | Name Value 239 | ---- ----- 240 | session logical reads 85 241 | db block gets 53 242 | db block gets from cache 53 243 | consistent gets 32 244 | consistent gets from cache 32 245 | consistent gets - examination 30 246 | db block changes 102 247 | 248 | redo synch writes 1 249 | redo synch time 1 250 | redo entries 1 251 | redo size 12,048 252 | 253 | undo change vector size 4,632 254 | IMU commits 1 255 | IMU undo allocation size 43,052 256 | 257 | buffer is not pinned count 20 258 | 259 | 260 | 261 | select name, count(*) from v$latch_children group by name order by count(*) 262 | 263 | NAME COUNT(*) 264 | -------------------------- ---------- 265 | In memory undo latch 10 266 | redo allocation 12 267 | 268 | 269 | 270 | Latch activity (hypothesis): 271 | on update: session gets allocation latch for private thread 272 | on commit: session gets allocation latch for private thread 273 | session gets allocation latch for a public thread - start with immediate get 274 | lgwr gets allocation latches for both public threads. 275 | 276 | # 277 | 278 | # 279 | 280 | -------------------------------------------------------------------------------- /ch_02/core_imu_01.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_demo_02.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: Feb 2011 5 | rem Purpose: 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 10.2.0.3 10 | rem Not relevant 11 | rem 9.2.0.8 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Can only be run as SYS in this form 16 | rem 17 | rem Diagnostics for core undo/redo concepts 18 | rem 19 | 20 | column indx format 9999 21 | 22 | -- Size of in-memory undo and private redo after a small change 23 | 24 | select 25 | indx, 26 | to_number(ktifpupe,'XXXXXXXX') - 27 | to_number(ktifpupb,'XXXXXXXX') undo_size, 28 | to_number(ktifpupc,'XXXXXXXX') - 29 | to_number(ktifpupb,'XXXXXXXX') undo_usage, 30 | to_number(ktifprpe,'XXXXXXXX') - 31 | to_number(ktifprpb,'XXXXXXXX') redo_size, 32 | to_number(ktifprpc,'XXXXXXXX') - 33 | to_number(ktifprpb,'XXXXXXXX') redo_usage 34 | from 35 | x$ktifp 36 | ; 37 | 38 | -- Sizes of private redo 39 | 40 | 41 | select 42 | indx, 43 | PNEXT_BUF_KCRFA_CLN, 44 | PTR_KCRF_PVT_STRAND, 45 | FIRST_BUF_KCRFA, 46 | LAST_BUF_KCRFA, 47 | -- LASTCHANGE_KCRFA, not available in 11.2 48 | STRAND_SIZE_KCRFA strand_size, 49 | SPACE_KCRF_PVT_STRAND strand_space 50 | from 51 | x$kcrfstrand 52 | ; 53 | -------------------------------------------------------------------------------- /ch_02/setenv.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: setenv.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: June 2002 5 | rem Purpose: Set up various SQL*Plus formatting commands. 6 | rem 7 | rem Notes: 8 | rem 9 | 10 | set pause off 11 | 12 | rem 13 | rem If you want to call dbms_xplan.display_cursor() to get the 14 | rem place for the last statement you executed you will have to 15 | rem set serveroutput off 16 | rem 17 | 18 | set serveroutput on size 1000000 format wrapped 19 | 20 | rem 21 | rem I'd like to enable java output, but it seems 22 | rem to push the UGA up by about 4MB when I do it 23 | rem 24 | 25 | rem execute dbms_java.set_output(1000000) 26 | 27 | rem 28 | rem Reminder about DOC, and using the # to end DOC 29 | rem the SET command stops doc material from appearing 30 | rem 31 | 32 | execute dbms_random.seed(0) 33 | 34 | set doc off 35 | doc 36 | 37 | end doc is marked with # 38 | 39 | # 40 | 41 | set linesize 120 42 | set trimspool on 43 | set pagesize 24 44 | set arraysize 25 45 | 46 | -- set longchunksize 32768 47 | -- set long 32768 48 | 49 | set autotrace off 50 | 51 | clear breaks 52 | ttitle off 53 | btitle off 54 | 55 | column owner format a15 56 | column segment_name format a20 57 | column table_name format a20 58 | column index_name format a20 59 | column object_name format a20 60 | column subobject_name format a20 61 | column partition_name format a20 62 | column subpartition_name format a20 63 | column column_name format a20 64 | column column_expression format a40 word wrap 65 | column constraint_name format a20 66 | 67 | column referenced_name format a30 68 | 69 | column file_name format a60 70 | 71 | column low_value format a24 72 | column high_value format a24 73 | 74 | column parent_id_plus_exp format 999 75 | column id_plus_exp format 990 76 | column plan_plus_exp format a90 77 | column object_node_plus_exp format a14 78 | column other_plus_exp format a90 79 | column other_tag_plus_exp format a29 80 | 81 | column access_predicates format a80 82 | column filter_predicates format a80 83 | column projection format a80 84 | column remarks format a80 85 | column partition_start format a12 86 | column partition_stop format a12 87 | column partition_id format 999 88 | column other_tag format a32 89 | column object_alias format a24 90 | 91 | column object_node format a13 92 | column other format a150 93 | 94 | column os_username format a30 95 | column terminal format a24 96 | column userhost format a24 97 | column client_id format a24 98 | 99 | column statistic_name format a35 100 | 101 | column namespace format a20 102 | column attribute format a20 103 | 104 | column hint format a40 105 | 106 | column start_time format a25 107 | column end_time format a25 108 | 109 | column time_now noprint new_value m_timestamp 110 | 111 | set feedback off 112 | 113 | select to_char(sysdate,'hh24miss') time_now from dual; 114 | commit; 115 | 116 | set feedback on 117 | 118 | set timing off 119 | set verify off 120 | 121 | alter session set optimizer_mode = all_rows; 122 | 123 | spool log 124 | 125 | -------------------------------------------------------------------------------- /ch_02/snap_11_latch.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_11_latch.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: Jan 2008 5 | rem Purpose: Package to get snapshot start and delta of latch stats 6 | rem 7 | rem Notes 8 | rem Version 11 specific 9 | rem Has to be run by SYS to create the package 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 168 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap 16 | rem -- do something 17 | rem execute snap_latch.end_snap 18 | rem 19 | rem We only capture sleep1 to sleep3 as the rest are fake columns 20 | rem and do not (appear to) capture any data. 21 | rem 22 | rem We could consider not selecting the latch name in the main 23 | rem cursor, and use the latch number to get the latch name from 24 | rem x$kslld at print time, as this would reduce the memory demand 25 | rem of the package 26 | rem 27 | 28 | create or replace package snap_latch as 29 | procedure start_snap; 30 | procedure end_snap( 31 | i_limit in number default 0, 32 | i_all_sleeps in boolean default false 33 | ); 34 | end; 35 | / 36 | 37 | create or replace package body snap_latch as 38 | 39 | cursor c1 is 40 | select 41 | lt.kslltnum indx, 42 | lt.kslltnam name, 43 | lt.ksllthsh, 44 | lt.kslltwgt gets, 45 | lt.kslltwff misses, 46 | lt.kslltwsl sleeps, 47 | lt.kslltngt immediate_gets, 48 | lt.kslltnfa immediate_misses, 49 | lt.kslltwkc waiters_woken, 50 | lt.kslltwth waits_holding_latch, 51 | lt.ksllthst0 spin_gets, 52 | lt.ksllthst1 sleep1, 53 | lt.ksllthst2 sleep2, 54 | lt.ksllthst3 sleep3, 55 | lt.kslltwtt/1000 wait_time 56 | from 57 | x$kslltr lt 58 | order by 59 | lt.kslltnum 60 | ; 61 | 62 | 63 | type w_type is table of c1%rowtype index by binary_integer; 64 | w_list w_type; 65 | w_empty_list w_type; 66 | 67 | m_start_time date; 68 | m_start_flag char(1); 69 | m_end_time date; 70 | 71 | procedure start_snap is 72 | begin 73 | 74 | m_start_time := sysdate; 75 | m_start_flag := 'U'; 76 | w_list := w_empty_list; 77 | 78 | for r in c1 loop 79 | w_list(r.indx).gets := r.gets; 80 | w_list(r.indx).misses := r.misses; 81 | w_list(r.indx).sleeps := r.sleeps; 82 | w_list(r.indx).sleep1 := r.sleep1; 83 | w_list(r.indx).sleep2 := r.sleep2; 84 | w_list(r.indx).sleep3 := r.sleep3; 85 | w_list(r.indx).spin_gets := r.spin_gets; 86 | w_list(r.indx).immediate_gets := r.immediate_gets; 87 | w_list(r.indx).immediate_misses := r.immediate_misses; 88 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 89 | w_list(r.indx).waiters_woken := r.waiters_woken; 90 | w_list(r.indx).wait_time := r.wait_time; 91 | end loop; 92 | 93 | end start_snap; 94 | 95 | 96 | procedure end_snap( 97 | i_limit in number default 0, 98 | i_all_sleeps in boolean default false 99 | ) 100 | is 101 | begin 102 | 103 | m_end_time := sysdate; 104 | 105 | dbms_output.put_line('---------------------------------'); 106 | dbms_output.put_line('Latch waits:- ' || 107 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 108 | ); 109 | 110 | if m_start_flag = 'U' then 111 | dbms_output.put_line('Interval:- ' || 112 | trunc(86400 * (m_end_time - m_start_time)) || 113 | ' seconds' 114 | ); 115 | else 116 | dbms_output.put_line('Since Startup:- ' || 117 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 118 | ); 119 | end if; 120 | 121 | if (i_limit != 0) then 122 | dbms_output.put_line('Lower limit:- ' || i_limit); 123 | end if; 124 | 125 | dbms_output.put_line('---------------------------------'); 126 | 127 | dbms_output.put( 128 | rpad('Latch',24) || 129 | lpad('Gets',15) || 130 | lpad('Misses',12) || 131 | lpad('Sp_Get',11) || 132 | lpad('Sleeps',11) 133 | ); 134 | 135 | if (i_all_sleeps) then 136 | dbms_output.put( 137 | lpad('Sleep1',11) || 138 | lpad('Sleep2',11) || 139 | lpad('Sleep3',11) 140 | ); 141 | end if; 142 | 143 | dbms_output.put_line( 144 | lpad('Im_Gets',12) || 145 | lpad('Im_Miss',10) || 146 | lpad('Holding',8) || 147 | lpad('Woken',6) || 148 | lpad('Time ms',8) 149 | ); 150 | 151 | dbms_output.put( 152 | rpad('-----',24) || 153 | lpad('----',15) || 154 | lpad('------',12) || 155 | lpad('------',11) || 156 | lpad('------',11) 157 | ); 158 | 159 | if (i_all_sleeps) then 160 | dbms_output.put( 161 | lpad('------',11) || 162 | lpad('------',11) || 163 | lpad('------',11) 164 | ); 165 | end if; 166 | 167 | dbms_output.put_line( 168 | lpad('-------',12) || 169 | lpad('-------',10) || 170 | lpad('-------',8) || 171 | lpad('-----',6) || 172 | lpad('-------',8) 173 | ); 174 | 175 | for r in c1 loop 176 | if (not w_list.exists(r.indx)) then 177 | w_list(r.indx).gets := 0; 178 | w_list(r.indx).misses := 0; 179 | w_list(r.indx).sleeps := 0; 180 | w_list(r.indx).sleep1 := 0; 181 | w_list(r.indx).sleep2 := 0; 182 | w_list(r.indx).sleep3 := 0; 183 | w_list(r.indx).spin_gets := 0; 184 | w_list(r.indx).immediate_gets := 0; 185 | w_list(r.indx).immediate_misses := 0; 186 | w_list(r.indx).waits_holding_latch := 0; 187 | w_list(r.indx).waiters_woken := 0; 188 | w_list(r.indx).wait_time := 0; 189 | end if; 190 | 191 | if ( 192 | (r.gets > w_list(r.indx).gets + i_limit) 193 | or (r.immediate_gets > w_list(r.indx).immediate_gets + i_limit) 194 | or (r.wait_time > w_list(r.indx).wait_time + i_limit) 195 | /* 196 | or (w_list(r.indx).misses != r.misses) 197 | or (w_list(r.indx).sleeps != r.sleeps) 198 | or (w_list(r.indx).sleep1 != r.sleep1) 199 | or (w_list(r.indx).sleep2 != r.sleep2) 200 | or (w_list(r.indx).sleep3 != r.sleep3) 201 | or (w_list(r.indx).spin_gets != r.spin_gets) 202 | or (w_list(r.indx).immediate_misses != r.immediate_misses) 203 | or (w_list(r.indx).waits_holding_latch != r.waits_holding_latch) 204 | or (w_list(r.indx).waiters_woken != r.waiters_woken) 205 | */ 206 | ) then 207 | 208 | dbms_output.put(rpad(substr(r.name,1,24),24)); 209 | dbms_output.put(to_char( 210 | r.gets - w_list(r.indx).gets, 211 | '99,999,999,990') 212 | ); 213 | dbms_output.put(to_char( 214 | r.misses - w_list(r.indx).misses, 215 | '999,999,990') 216 | ); 217 | dbms_output.put(to_char( 218 | r.spin_gets - w_list(r.indx).spin_gets, 219 | '99,999,990') 220 | ); 221 | dbms_output.put(to_char( 222 | r.sleeps - w_list(r.indx).sleeps, 223 | '99,999,990') 224 | ); 225 | 226 | if (i_all_sleeps) then 227 | dbms_output.put(to_char( 228 | r.sleep1 - w_list(r.indx).sleep1, 229 | '99,999,990') 230 | ); 231 | dbms_output.put(to_char( 232 | r.sleep2 - w_list(r.indx).sleep2, 233 | '99,999,990') 234 | ); 235 | dbms_output.put(to_char( 236 | r.sleep3 - w_list(r.indx).sleep3, 237 | '99,999,990') 238 | ); 239 | end if; 240 | 241 | dbms_output.put(to_char( 242 | r.immediate_gets - w_list(r.indx).immediate_gets, 243 | '999,999,990') 244 | ); 245 | dbms_output.put(to_char( 246 | r.immediate_misses - w_list(r.indx).immediate_misses, 247 | '9,999,990') 248 | ); 249 | dbms_output.put(to_char( 250 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 251 | '999,990') 252 | ); 253 | dbms_output.put(to_char( 254 | r.waiters_woken - w_list(r.indx).waiters_woken, 255 | '9,990') 256 | ); 257 | dbms_output.put(to_char( 258 | r.wait_time - w_list(r.indx).wait_time, 259 | '9,999.0') 260 | ); 261 | dbms_output.new_line; 262 | end if; 263 | 264 | end loop; 265 | 266 | 267 | end end_snap; 268 | 269 | begin 270 | select 271 | startup_time, 'S' 272 | into 273 | m_start_time, m_start_flag 274 | from 275 | v$instance; 276 | 277 | end snap_latch; 278 | / 279 | 280 | 281 | drop public synonym snap_latch; 282 | create public synonym snap_latch for snap_latch; 283 | grant execute on snap_latch to public; 284 | -------------------------------------------------------------------------------- /ch_02/snap_9_latch.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_latch.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of latch stats 6 | rem 7 | rem Notes 8 | rem Version 9/10 specific - remove references to wait_time for version 8 9 | rem Has to be run by SYS to create the package 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 168 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap 16 | rem -- do something 17 | rem execute snap_latch.end_snap 18 | rem 19 | rem We only capture sleep1 to sleep3 as the rest are fake columns 20 | rem and do not (appear to) capture any data. 21 | rem 22 | rem We could consider not selecting the latch name in the main 23 | rem cursor, and use the latch number to get the latch name from 24 | rem x$kslld at print time, as this would reduce the memory demand 25 | rem of the package 26 | rem 27 | 28 | create or replace package snap_latch as 29 | procedure start_snap; 30 | procedure end_snap( 31 | i_limit in number default 0, 32 | i_all_sleeps in boolean default false 33 | ); 34 | end; 35 | / 36 | 37 | create or replace package body snap_latch as 38 | 39 | cursor c1 is 40 | select 41 | la.latch# indx, 42 | d.kslldnam name, 43 | la.gets, 44 | la.misses, 45 | la.sleeps, 46 | la.sleep1, 47 | la.sleep2, 48 | la.sleep3, 49 | la.immediate_gets, 50 | la.immediate_misses, 51 | la.spin_gets, 52 | la.waits_holding_latch, 53 | la.waiters_woken, 54 | round(la.wait_time/1000,1) wait_time 55 | from 56 | x$kslld d, 57 | ( 58 | select 59 | kslltnum latch#, 60 | sum(kslltwgt) gets, 61 | sum(kslltwff) misses, 62 | sum(kslltwsl) sleeps, 63 | sum(kslltngt) immediate_gets, 64 | sum(kslltnfa) immediate_misses, 65 | sum(kslltwkc) waiters_woken, 66 | sum(kslltwth) waits_holding_latch, 67 | sum(ksllthst0) spin_gets, 68 | sum(ksllthst1) sleep1, 69 | sum(ksllthst2) sleep2, 70 | sum(ksllthst3) sleep3, 71 | sum(kslltwtt) wait_time 72 | from 73 | x$ksllt 74 | group by kslltnum 75 | ) la 76 | where la.latch# = d.indx 77 | order by 78 | la.latch# 79 | ; 80 | 81 | 82 | type w_type is table of c1%rowtype index by binary_integer; 83 | w_list w_type; 84 | w_empty_list w_type; 85 | 86 | m_start_time date; 87 | m_start_flag char(1); 88 | m_end_time date; 89 | 90 | procedure start_snap is 91 | begin 92 | 93 | m_start_time := sysdate; 94 | m_start_flag := 'U'; 95 | w_list := w_empty_list; 96 | 97 | for r in c1 loop 98 | w_list(r.indx).gets := r.gets; 99 | w_list(r.indx).misses := r.misses; 100 | w_list(r.indx).sleeps := r.sleeps; 101 | w_list(r.indx).sleep1 := r.sleep1; 102 | w_list(r.indx).sleep2 := r.sleep2; 103 | w_list(r.indx).sleep3 := r.sleep3; 104 | w_list(r.indx).spin_gets := r.spin_gets; 105 | w_list(r.indx).immediate_gets := r.immediate_gets; 106 | w_list(r.indx).immediate_misses := r.immediate_misses; 107 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 108 | w_list(r.indx).waiters_woken := r.waiters_woken; 109 | w_list(r.indx).wait_time := r.wait_time; 110 | end loop; 111 | 112 | end start_snap; 113 | 114 | 115 | procedure end_snap( 116 | i_limit in number default 0, 117 | i_all_sleeps in boolean default false 118 | ) 119 | is 120 | begin 121 | 122 | m_end_time := sysdate; 123 | 124 | dbms_output.put_line('---------------------------------'); 125 | dbms_output.put_line('Latch waits:- ' || 126 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 127 | ); 128 | 129 | if m_start_flag = 'U' then 130 | dbms_output.put_line('Interval:- ' || 131 | trunc(86400 * (m_end_time - m_start_time)) || 132 | ' seconds' 133 | ); 134 | else 135 | dbms_output.put_line('Since Startup:- ' || 136 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 137 | ); 138 | end if; 139 | 140 | if (i_limit != 0) then 141 | dbms_output.put_line('Lower limit:- ' || i_limit); 142 | end if; 143 | 144 | dbms_output.put_line('---------------------------------'); 145 | 146 | dbms_output.put( 147 | rpad('Latch',24) || 148 | lpad('Gets',15) || 149 | lpad('Misses',12) || 150 | lpad('Sp_Get',11) || 151 | lpad('Sleeps',11) 152 | ); 153 | 154 | if (i_all_sleeps) then 155 | dbms_output.put( 156 | lpad('Sleep1',11) || 157 | lpad('Sleep2',11) || 158 | lpad('Sleep3',11) 159 | ); 160 | end if; 161 | 162 | dbms_output.put_line( 163 | lpad('Im_Gets',12) || 164 | lpad('Im_Miss',10) || 165 | lpad('Holding',8) || 166 | lpad('Woken',6) || 167 | lpad('Time ms',8) 168 | ); 169 | 170 | dbms_output.put( 171 | rpad('-----',24) || 172 | lpad('----',15) || 173 | lpad('------',12) || 174 | lpad('------',11) || 175 | lpad('------',11) 176 | ); 177 | 178 | if (i_all_sleeps) then 179 | dbms_output.put( 180 | lpad('------',11) || 181 | lpad('------',11) || 182 | lpad('------',11) 183 | ); 184 | end if; 185 | 186 | dbms_output.put_line( 187 | lpad('-------',12) || 188 | lpad('-------',10) || 189 | lpad('-------',8) || 190 | lpad('-----',6) || 191 | lpad('-------',8) 192 | ); 193 | 194 | for r in c1 loop 195 | if (not w_list.exists(r.indx)) then 196 | w_list(r.indx).gets := 0; 197 | w_list(r.indx).misses := 0; 198 | w_list(r.indx).sleeps := 0; 199 | w_list(r.indx).sleep1 := 0; 200 | w_list(r.indx).sleep2 := 0; 201 | w_list(r.indx).sleep3 := 0; 202 | w_list(r.indx).spin_gets := 0; 203 | w_list(r.indx).immediate_gets := 0; 204 | w_list(r.indx).immediate_misses := 0; 205 | w_list(r.indx).waits_holding_latch := 0; 206 | w_list(r.indx).waiters_woken := 0; 207 | w_list(r.indx).wait_time := 0; 208 | end if; 209 | 210 | if ( 211 | (r.gets > w_list(r.indx).gets + i_limit) 212 | or (r.immediate_gets > w_list(r.indx).immediate_gets + i_limit) 213 | or (r.wait_time > w_list(r.indx).wait_time + i_limit) 214 | /* 215 | or (w_list(r.indx).misses != r.misses) 216 | or (w_list(r.indx).sleeps != r.sleeps) 217 | or (w_list(r.indx).sleep1 != r.sleep1) 218 | or (w_list(r.indx).sleep2 != r.sleep2) 219 | or (w_list(r.indx).sleep3 != r.sleep3) 220 | or (w_list(r.indx).spin_gets != r.spin_gets) 221 | or (w_list(r.indx).immediate_misses != r.immediate_misses) 222 | or (w_list(r.indx).waits_holding_latch != r.waits_holding_latch) 223 | or (w_list(r.indx).waiters_woken != r.waiters_woken) 224 | */ 225 | ) then 226 | 227 | dbms_output.put(rpad(substr(r.name,1,24),24)); 228 | dbms_output.put(to_char( 229 | r.gets - w_list(r.indx).gets, 230 | '99,999,999,990') 231 | ); 232 | dbms_output.put(to_char( 233 | r.misses - w_list(r.indx).misses, 234 | '999,999,990') 235 | ); 236 | dbms_output.put(to_char( 237 | r.spin_gets - w_list(r.indx).spin_gets, 238 | '99,999,990') 239 | ); 240 | dbms_output.put(to_char( 241 | r.sleeps - w_list(r.indx).sleeps, 242 | '99,999,990') 243 | ); 244 | 245 | if (i_all_sleeps) then 246 | dbms_output.put(to_char( 247 | r.sleep1 - w_list(r.indx).sleep1, 248 | '99,999,990') 249 | ); 250 | dbms_output.put(to_char( 251 | r.sleep2 - w_list(r.indx).sleep2, 252 | '99,999,990') 253 | ); 254 | dbms_output.put(to_char( 255 | r.sleep3 - w_list(r.indx).sleep3, 256 | '99,999,990') 257 | ); 258 | end if; 259 | 260 | dbms_output.put(to_char( 261 | r.immediate_gets - w_list(r.indx).immediate_gets, 262 | '999,999,990') 263 | ); 264 | dbms_output.put(to_char( 265 | r.immediate_misses - w_list(r.indx).immediate_misses, 266 | '9,999,990') 267 | ); 268 | dbms_output.put(to_char( 269 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 270 | '999,990') 271 | ); 272 | dbms_output.put(to_char( 273 | r.waiters_woken - w_list(r.indx).waiters_woken, 274 | '9,990') 275 | ); 276 | dbms_output.put(to_char( 277 | r.wait_time - w_list(r.indx).wait_time, 278 | '9,999.0') 279 | ); 280 | dbms_output.new_line; 281 | end if; 282 | 283 | end loop; 284 | 285 | 286 | end end_snap; 287 | 288 | begin 289 | select 290 | startup_time, 'S' 291 | into 292 | m_start_time, m_start_flag 293 | from 294 | v$instance; 295 | 296 | end snap_latch; 297 | / 298 | 299 | 300 | drop public synonym snap_latch; 301 | create public synonym snap_latch for snap_latch; 302 | grant execute on snap_latch to public; 303 | -------------------------------------------------------------------------------- /ch_02/snap_9_latch_child.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_latch_child.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of latch child stats 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Version 9/10 specific - remove references to wait_time for version 8 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap_cbc 16 | rem -- do something 17 | rem execute snap_latch.end_snap_cbc 18 | rem 19 | rem Optionally capture sleep1, sleep2, sleep3. The rest (4 - 11) 20 | rem are fake columns, not populated by Oracle 21 | rem 22 | 23 | create or replace package snap_latch_child as 24 | 25 | procedure start_snap(i_latch in varchar2); 26 | procedure end_snap(i_latch in varchar2, i_all_sleeps in boolean default false); 27 | 28 | procedure start_snap_cbc; 29 | procedure end_snap_cbc(i_all_sleeps in boolean default false); 30 | 31 | end; 32 | / 33 | 34 | create or replace package body snap_latch_child as 35 | 36 | cursor c1 (i_latch in varchar2) is 37 | select 38 | la.addr, 39 | la.child# indx, 40 | la.gets, 41 | la.misses, 42 | la.sleeps, 43 | la.sleep1, 44 | la.sleep2, 45 | la.sleep3, 46 | la.immediate_gets, 47 | la.immediate_misses, 48 | la.spin_gets, 49 | la.waits_holding_latch, 50 | la.waiters_woken, 51 | round(la.wait_time/1000,3) wait_time 52 | from 53 | v$latch_children la 54 | where la.name = i_latch 55 | order by 56 | la.child# 57 | ; 58 | 59 | type w_type is table of c1%rowtype index by binary_integer; 60 | w_list w_type; 61 | w_empty_list w_type; 62 | 63 | m_start_time date; 64 | m_start_flag char(1); 65 | m_end_time date; 66 | 67 | procedure start_snap (i_latch in varchar2) is 68 | begin 69 | 70 | m_start_time := sysdate; 71 | m_start_flag := 'U'; 72 | w_list := w_empty_list; 73 | 74 | for r in c1(i_latch) loop 75 | w_list(r.indx).gets := r.gets; 76 | w_list(r.indx).misses := r.misses; 77 | w_list(r.indx).sleeps := r.sleeps; 78 | w_list(r.indx).sleep1 := r.sleep1; 79 | w_list(r.indx).sleep2 := r.sleep2; 80 | w_list(r.indx).sleep3 := r.sleep3; 81 | w_list(r.indx).spin_gets := r.spin_gets; 82 | w_list(r.indx).immediate_gets := r.immediate_gets; 83 | w_list(r.indx).immediate_misses := r.immediate_misses; 84 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 85 | w_list(r.indx).waiters_woken := r.waiters_woken; 86 | w_list(r.indx).wait_time := r.wait_time; 87 | end loop; 88 | 89 | 90 | end start_snap; 91 | 92 | 93 | procedure end_snap(i_latch in varchar2, i_all_sleeps in boolean default false) is 94 | 95 | m_latch_count number(6) := 0; 96 | begin 97 | 98 | 99 | m_end_time := sysdate; 100 | 101 | dbms_output.put_line('---------------------------------------------------------'); 102 | dbms_output.put_line(i_latch || ' latch waits - ' || 103 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 104 | ); 105 | 106 | if m_start_flag = 'U' then 107 | dbms_output.put_line('Interval:- ' || 108 | trunc(86400 * (m_end_time - m_start_time)) || 109 | ' seconds' 110 | ); 111 | else 112 | dbms_output.put_line('Since Startup:- ' || 113 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 114 | ); 115 | end if; 116 | 117 | dbms_output.put_line('---------------------------------------------------------'); 118 | 119 | dbms_output.put( 120 | rpad('Address',17) || 121 | lpad('Gets',15) || 122 | lpad('Misses',12) || 123 | lpad('Spins',11) || 124 | lpad('Sleeps',11) 125 | ); 126 | 127 | if (i_all_sleeps) then 128 | dbms_output.put( 129 | lpad('Sleep1',11) || 130 | lpad('Sleep2',11) || 131 | lpad('Sleep3',11) 132 | ); 133 | end if; 134 | 135 | dbms_output.put_line( 136 | lpad('Im_Gets',14) || 137 | lpad('Im_Miss',12) || 138 | lpad('Holding',8) || 139 | lpad('Woken',6) || 140 | lpad('Time m/s',12) 141 | ); 142 | 143 | dbms_output.put( 144 | rpad('-------',17) || 145 | lpad('----',15) || 146 | lpad('------',12) || 147 | lpad('------',11) || 148 | lpad('-----',11) 149 | ); 150 | 151 | if (i_all_sleeps) then 152 | dbms_output.put( 153 | lpad('-----',11) || 154 | lpad('-----',11) || 155 | lpad('------',11) 156 | ); 157 | end if; 158 | 159 | dbms_output.put_line( 160 | lpad('-------',14) || 161 | lpad('-------',12) || 162 | lpad('-------',8) || 163 | lpad('-----',6) || 164 | lpad('--------',12) 165 | ); 166 | 167 | for r in c1(i_latch) loop 168 | if (not w_list.exists(r.indx)) then 169 | w_list(r.indx).gets := 0; 170 | w_list(r.indx).misses := 0; 171 | w_list(r.indx).sleeps := 0; 172 | w_list(r.indx).sleep1 := 0; 173 | w_list(r.indx).sleep2 := 0; 174 | w_list(r.indx).sleep3 := 0; 175 | w_list(r.indx).spin_gets := 0; 176 | w_list(r.indx).immediate_gets := 0; 177 | w_list(r.indx).immediate_misses := 0; 178 | w_list(r.indx).waits_holding_latch := 0; 179 | w_list(r.indx).waiters_woken := 0; 180 | w_list(r.indx).wait_time := 0; 181 | end if; 182 | 183 | if ( 184 | w_list(r.indx).gets != r.gets 185 | or w_list(r.indx).misses != r.misses 186 | or w_list(r.indx).sleeps != r.sleeps 187 | or w_list(r.indx).sleep1 != r.sleep1 188 | or w_list(r.indx).sleep2 != r.sleep2 189 | or w_list(r.indx).sleep3 != r.sleep3 190 | or w_list(r.indx).spin_gets != r.spin_gets 191 | or w_list(r.indx).immediate_gets != r.immediate_gets 192 | or w_list(r.indx).immediate_misses != r.immediate_misses 193 | or w_list(r.indx).waits_holding_latch != r.waits_holding_latch 194 | or w_list(r.indx).waiters_woken != r.waiters_woken 195 | or w_list(r.indx).wait_time != r.wait_time 196 | ) then 197 | m_latch_count := m_latch_count + 1; 198 | 199 | dbms_output.put(rpad(r.addr,17)); 200 | dbms_output.put(to_char( 201 | r.gets - w_list(r.indx).gets, 202 | '99,999,999,990') 203 | ); 204 | dbms_output.put(to_char( 205 | r.misses - w_list(r.indx).misses, 206 | '999,999,990') 207 | ); 208 | dbms_output.put(to_char( 209 | r.spin_gets - w_list(r.indx).spin_gets, 210 | '99,999,990') 211 | ); 212 | dbms_output.put(to_char( 213 | r.sleeps - w_list(r.indx).sleeps, 214 | '99,999,990') 215 | ); 216 | 217 | if (i_all_sleeps) then 218 | dbms_output.put(to_char( 219 | r.sleep1 - w_list(r.indx).sleep1, 220 | '99,999,990') 221 | ); 222 | dbms_output.put(to_char( 223 | r.sleep2 - w_list(r.indx).sleep2, 224 | '99,999,990') 225 | ); 226 | dbms_output.put(to_char( 227 | r.sleep3 - w_list(r.indx).sleep3, 228 | '99,999,990') 229 | ); 230 | end if; 231 | 232 | dbms_output.put(to_char( 233 | r.immediate_gets - w_list(r.indx).immediate_gets, 234 | '9,999,999,990') 235 | ); 236 | dbms_output.put(to_char( 237 | r.immediate_misses - w_list(r.indx).immediate_misses, 238 | '999,999,990') 239 | ); 240 | dbms_output.put(to_char( 241 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 242 | '999,990') 243 | ); 244 | dbms_output.put(to_char( 245 | r.waiters_woken - w_list(r.indx).waiters_woken, 246 | '9,990') 247 | ); 248 | dbms_output.put(to_char( 249 | r.wait_time - w_list(r.indx).wait_time, 250 | '999,999.990') 251 | ); 252 | dbms_output.new_line; 253 | end if; 254 | 255 | end loop; 256 | 257 | dbms_output.put_line('Latches reported: ' || m_latch_count); 258 | 259 | end end_snap; 260 | 261 | procedure start_snap_cbc is 262 | begin 263 | start_snap('cache buffers chains'); 264 | end; 265 | 266 | procedure end_snap_cbc(i_all_sleeps in boolean default false) is 267 | begin 268 | end_snap('cache buffers chains', i_all_sleeps); 269 | end; 270 | 271 | begin 272 | select 273 | startup_time, 'S' 274 | into 275 | m_start_time, m_start_flag 276 | from 277 | v$instance; 278 | 279 | end snap_latch_child; 280 | / 281 | 282 | 283 | drop public synonym snap_latch_child; 284 | create public synonym snap_latch_child for snap_latch_child; 285 | grant execute on snap_latch_child to public; 286 | -------------------------------------------------------------------------------- /ch_02/snap_9_latch_parent.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_latch_parent.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of latch child stats 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Version 9/10 specific - remove references to wait_time for version 8 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap_cbc 16 | rem -- do something 17 | rem execute snap_latch.end_snap_cbc 18 | rem 19 | rem Optionally capture sleep1, sleep2, sleep3. The rest (4 - 11) 20 | rem are fake columns, not populated by Oracle 21 | rem 22 | 23 | create or replace package snap_latch_parent as 24 | 25 | procedure start_snap; 26 | procedure end_snap(i_all_sleeps in boolean default false); 27 | 28 | end; 29 | / 30 | 31 | create or replace package body snap_latch_parent as 32 | 33 | cursor c1 is 34 | select 35 | la.name, 36 | la.latch# indx, 37 | la.gets, 38 | la.misses, 39 | la.sleeps, 40 | la.sleep1, 41 | la.sleep2, 42 | la.sleep3, 43 | la.immediate_gets, 44 | la.immediate_misses, 45 | la.spin_gets, 46 | la.waits_holding_latch, 47 | la.waiters_woken, 48 | round(la.wait_time/1000,3) wait_time 49 | from 50 | v$latch_parent la 51 | order by 52 | latch# 53 | ; 54 | 55 | type w_type is table of c1%rowtype index by binary_integer; 56 | w_list w_type; 57 | w_empty_list w_type; 58 | 59 | m_start_time date; 60 | m_start_flag char(1); 61 | m_end_time date; 62 | 63 | procedure start_snap is 64 | begin 65 | 66 | m_start_time := sysdate; 67 | m_start_flag := 'U'; 68 | w_list := w_empty_list; 69 | 70 | for r in c1 loop 71 | w_list(r.indx).gets := r.gets; 72 | w_list(r.indx).misses := r.misses; 73 | w_list(r.indx).sleeps := r.sleeps; 74 | w_list(r.indx).sleep1 := r.sleep1; 75 | w_list(r.indx).sleep2 := r.sleep2; 76 | w_list(r.indx).sleep3 := r.sleep3; 77 | w_list(r.indx).spin_gets := r.spin_gets; 78 | w_list(r.indx).immediate_gets := r.immediate_gets; 79 | w_list(r.indx).immediate_misses := r.immediate_misses; 80 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 81 | w_list(r.indx).waiters_woken := r.waiters_woken; 82 | w_list(r.indx).wait_time := r.wait_time; 83 | end loop; 84 | 85 | 86 | end start_snap; 87 | 88 | 89 | procedure end_snap(i_all_sleeps in boolean default false) is 90 | begin 91 | 92 | m_end_time := sysdate; 93 | 94 | dbms_output.put_line('---------------------------------------------------------'); 95 | dbms_output.put_line('Parent latch waits - ' || 96 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 97 | ); 98 | 99 | if m_start_flag = 'U' then 100 | dbms_output.put_line('Interval:- ' || 101 | trunc(86400 * (m_end_time - m_start_time)) || 102 | ' seconds' 103 | ); 104 | else 105 | dbms_output.put_line('Since Startup:- ' || 106 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 107 | ); 108 | end if; 109 | 110 | dbms_output.put_line('---------------------------------------------------------'); 111 | 112 | dbms_output.put( 113 | rpad('Name',24) || 114 | lpad('Gets',15) || 115 | lpad('Misses',12) || 116 | lpad('Spins',11) || 117 | lpad('Sleeps',11) 118 | ); 119 | 120 | if (i_all_sleeps) then 121 | dbms_output.put( 122 | lpad('Sleep1',11) || 123 | lpad('Sleep2',11) || 124 | lpad('Sleep3',11) 125 | ); 126 | end if; 127 | 128 | dbms_output.put_line( 129 | lpad('Im_Gets',14) || 130 | lpad('Im_Miss',12) || 131 | lpad('Holding',8) || 132 | lpad('Woken',6) || 133 | lpad('Time m/s',12) 134 | ); 135 | 136 | dbms_output.put( 137 | rpad('----',24) || 138 | lpad('----',15) || 139 | lpad('------',12) || 140 | lpad('------',11) || 141 | lpad('-----',11) 142 | ); 143 | 144 | if (i_all_sleeps) then 145 | dbms_output.put( 146 | lpad('-----',11) || 147 | lpad('-----',11) || 148 | lpad('------',11) 149 | ); 150 | end if; 151 | 152 | dbms_output.put_line( 153 | lpad('-------',14) || 154 | lpad('-------',12) || 155 | lpad('-------',8) || 156 | lpad('-----',6) || 157 | lpad('--------',12) 158 | ); 159 | 160 | for r in c1 loop 161 | if (not w_list.exists(r.indx)) then 162 | w_list(r.indx).gets := 0; 163 | w_list(r.indx).misses := 0; 164 | w_list(r.indx).sleeps := 0; 165 | w_list(r.indx).sleep1 := 0; 166 | w_list(r.indx).sleep2 := 0; 167 | w_list(r.indx).sleep3 := 0; 168 | w_list(r.indx).spin_gets := 0; 169 | w_list(r.indx).immediate_gets := 0; 170 | w_list(r.indx).immediate_misses := 0; 171 | w_list(r.indx).waits_holding_latch := 0; 172 | w_list(r.indx).waiters_woken := 0; 173 | w_list(r.indx).wait_time := 0; 174 | end if; 175 | 176 | if ( 177 | w_list(r.indx).gets != r.gets 178 | or w_list(r.indx).misses != r.misses 179 | or w_list(r.indx).sleeps != r.sleeps 180 | or w_list(r.indx).sleep1 != r.sleep1 181 | or w_list(r.indx).sleep2 != r.sleep2 182 | or w_list(r.indx).sleep3 != r.sleep3 183 | or w_list(r.indx).spin_gets != r.spin_gets 184 | or w_list(r.indx).immediate_gets != r.immediate_gets 185 | or w_list(r.indx).immediate_misses != r.immediate_misses 186 | or w_list(r.indx).waits_holding_latch != r.waits_holding_latch 187 | or w_list(r.indx).waiters_woken != r.waiters_woken 188 | or w_list(r.indx).wait_time != r.wait_time 189 | ) then 190 | 191 | dbms_output.put(rpad(r.name,24)); 192 | 193 | dbms_output.put(to_char( 194 | r.gets - w_list(r.indx).gets, 195 | '99,999,999,990') 196 | ); 197 | dbms_output.put(to_char( 198 | r.misses - w_list(r.indx).misses, 199 | '999,999,990') 200 | ); 201 | dbms_output.put(to_char( 202 | r.spin_gets - w_list(r.indx).spin_gets, 203 | '99,999,990') 204 | ); 205 | dbms_output.put(to_char( 206 | r.sleeps - w_list(r.indx).sleeps, 207 | '99,999,990') 208 | ); 209 | 210 | if (i_all_sleeps) then 211 | dbms_output.put(to_char( 212 | r.sleep1 - w_list(r.indx).sleep1, 213 | '99,999,990') 214 | ); 215 | dbms_output.put(to_char( 216 | r.sleep2 - w_list(r.indx).sleep2, 217 | '99,999,990') 218 | ); 219 | dbms_output.put(to_char( 220 | r.sleep3 - w_list(r.indx).sleep3, 221 | '99,999,990') 222 | ); 223 | end if; 224 | 225 | dbms_output.put(to_char( 226 | r.immediate_gets - w_list(r.indx).immediate_gets, 227 | '9,999,999,990') 228 | ); 229 | dbms_output.put(to_char( 230 | r.immediate_misses - w_list(r.indx).immediate_misses, 231 | '999,999,990') 232 | ); 233 | dbms_output.put(to_char( 234 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 235 | '999,990') 236 | ); 237 | dbms_output.put(to_char( 238 | r.waiters_woken - w_list(r.indx).waiters_woken, 239 | '9,990') 240 | ); 241 | dbms_output.put(to_char( 242 | r.wait_time - w_list(r.indx).wait_time, 243 | '999,999.990') 244 | ); 245 | dbms_output.new_line; 246 | end if; 247 | 248 | end loop; 249 | 250 | end end_snap; 251 | 252 | 253 | begin 254 | select 255 | startup_time, 'S' 256 | into 257 | m_start_time, m_start_flag 258 | from 259 | v$instance; 260 | 261 | end snap_latch_parent; 262 | / 263 | 264 | 265 | drop public synonym snap_latch_parent; 266 | create public synonym snap_latch_parent for snap_latch_parent; 267 | grant execute on snap_latch_parent to public; 268 | -------------------------------------------------------------------------------- /ch_02/snap_myst.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_myst.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$mystat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Depends on view v$my_stats (see c_mystats.sql) 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_my_stats.start_snap 16 | rem -- do something 17 | rem execute snap_my_stats.end_snap 18 | rem 19 | 20 | create or replace package snap_my_stats as 21 | procedure start_snap; 22 | procedure end_snap (i_limit in number default 0); 23 | end; 24 | / 25 | 26 | create or replace package body snap_my_stats as 27 | 28 | cursor c1 is 29 | select 30 | statistic#, 31 | name, 32 | value 33 | from 34 | v$my_stats 35 | where 36 | value != 0 37 | ; 38 | 39 | 40 | type w_type is table of c1%rowtype index by binary_integer; 41 | w_list w_type; 42 | empty_list w_type; 43 | 44 | m_start_time date; 45 | m_start_flag char(1); 46 | m_end_time date; 47 | 48 | procedure start_snap is 49 | begin 50 | 51 | m_start_time := sysdate; 52 | m_start_flag := 'U'; 53 | w_list := empty_list; 54 | 55 | for r in c1 loop 56 | w_list(r.statistic#).value := r.value; 57 | end loop; 58 | 59 | end start_snap; 60 | 61 | 62 | 63 | procedure end_snap (i_limit in number default 0) 64 | is 65 | begin 66 | 67 | m_end_time := sysdate; 68 | 69 | dbms_output.put_line('---------------------------------'); 70 | dbms_output.put_line('Session stats - ' || 71 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 72 | ); 73 | 74 | if m_start_flag = 'U' then 75 | dbms_output.put_line('Interval:- ' || 76 | trunc(86400 * (m_end_time - m_start_time)) || 77 | ' seconds' 78 | ); 79 | else 80 | dbms_output.put_line('Since Startup:- ' || 81 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 82 | ); 83 | end if; 84 | 85 | if (i_limit != 0) then 86 | dbms_output.put_line('Lower limit:- ' || i_limit); 87 | end if; 88 | 89 | dbms_output.put_line('---------------------------------'); 90 | 91 | dbms_output.put_line( 92 | rpad('Name',60) || 93 | lpad('Value',18) 94 | ); 95 | 96 | dbms_output.put_line( 97 | rpad('----',60) || 98 | lpad('-----',18) 99 | ); 100 | 101 | for r in c1 loop 102 | if (not w_list.exists(r.statistic#)) then 103 | w_list(r.statistic#).value := 0; 104 | end if; 105 | 106 | if ( 107 | (r.value > w_list(r.statistic#).value + i_limit) 108 | ) then 109 | dbms_output.put(rpad(r.name,60)); 110 | dbms_output.put(to_char( 111 | r.value - w_list(r.statistic#).value, 112 | '9,999,999,999,990') 113 | ); 114 | dbms_output.new_line; 115 | end if; 116 | end loop; 117 | 118 | end end_snap; 119 | 120 | begin 121 | select 122 | logon_time, 'S' 123 | into 124 | m_start_time, m_start_flag 125 | from 126 | v$session 127 | where 128 | sid = ( 129 | select /*+ no_unnest */ sid 130 | from v$mystat 131 | where rownum = 1 132 | ); 133 | 134 | end snap_my_stats; 135 | / 136 | 137 | 138 | drop public synonym snap_my_stats; 139 | create public synonym snap_my_stats for snap_my_stats; 140 | grant execute on snap_my_stats to public; 141 | -------------------------------------------------------------------------------- /ch_02/snap_stat.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_stat.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$sysstat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 120 13 | rem set trimspool on 14 | rem execute snap_stats.start_snap 15 | rem -- do something 16 | rem execute snap_stats.end_snap 17 | rem 18 | 19 | create or replace package snap_stats as 20 | procedure start_snap; 21 | procedure end_snap (i_limit in number default 0); 22 | end; 23 | / 24 | 25 | create or replace package body snap_stats as 26 | 27 | cursor c1 is 28 | select 29 | statistic#, 30 | name, 31 | value 32 | from 33 | v$sysstat 34 | ; 35 | 36 | 37 | type w_type is table of c1%rowtype index by binary_integer; 38 | w_list w_type; 39 | w_empty_list w_type; 40 | 41 | m_start_time date; 42 | m_start_flag char(1); 43 | m_end_time date; 44 | 45 | procedure start_snap is 46 | begin 47 | 48 | m_start_time := sysdate; 49 | m_start_flag := 'U'; 50 | w_list := w_empty_list; 51 | 52 | for r in c1 loop 53 | w_list(r.statistic#).value := r.value; 54 | end loop; 55 | 56 | end start_snap; 57 | 58 | 59 | procedure end_snap (i_limit in number default 0) 60 | is 61 | begin 62 | 63 | m_end_time := sysdate; 64 | 65 | dbms_output.put_line('---------------------------------'); 66 | dbms_output.put_line('System stats:- ' || 67 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 68 | ); 69 | 70 | if m_start_flag = 'U' then 71 | dbms_output.put_line('Interval:- ' || 72 | trunc(86400 * (m_end_time - m_start_time)) || 73 | ' seconds' 74 | ); 75 | else 76 | dbms_output.put_line('Since Startup:- ' || 77 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 78 | ); 79 | end if; 80 | 81 | if (i_limit != 0) then 82 | dbms_output.put_line('Lower limit:- ' || i_limit); 83 | end if; 84 | 85 | dbms_output.put_line('---------------------------------'); 86 | 87 | dbms_output.put_line( 88 | rpad('Name',60) || 89 | lpad('Value',18) 90 | ); 91 | 92 | dbms_output.put_line( 93 | rpad('----',60) || 94 | lpad('-----',18) 95 | ); 96 | 97 | for r in c1 loop 98 | if (not w_list.exists(r.statistic#)) then 99 | w_list(r.statistic#).value := 0; 100 | end if; 101 | 102 | if ( 103 | (r.value > w_list(r.statistic#).value + i_limit) 104 | ) then 105 | dbms_output.put(rpad(r.name,60)); 106 | dbms_output.put(to_char( 107 | r.value - w_list(r.statistic#).value, 108 | '9,999,999,999,990')); 109 | dbms_output.new_line; 110 | end if; 111 | end loop; 112 | 113 | end end_snap; 114 | 115 | begin 116 | 117 | select 118 | startup_time, 'S' 119 | into 120 | m_start_time, m_start_flag 121 | from 122 | v$instance 123 | ; 124 | 125 | end snap_stats; 126 | / 127 | 128 | 129 | drop public synonym snap_stats; 130 | create public synonym snap_stats for snap_stats; 131 | grant execute on snap_stats to public; 132 | -------------------------------------------------------------------------------- /ch_03/c_dump_seg.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_dump_seg.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: December 2002 5 | rem Purpose: Create a procedure to dump blocks from a segment 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 11.1.0.7 10 | rem 10.2.0.3 11 | rem 10.1.0.4 12 | rem 9.2.0.6 13 | rem 8.1.7.4 14 | rem 15 | rem Notes: 16 | rem The code is very simple minded with no error trapping. 17 | rem It only covers the first extent (extent zero) of a segment 18 | rem Could be enhanced to use get_ev to save and restore the state 19 | rem of event 10289 (the one that controls raw/cooked dumps). 20 | rem 21 | rem Change in 10.2: the raw block dump always appears in 22 | rem a block dump, you cannot stop it. Event 10289 blocks 23 | rem the appearance of the formatted dump 24 | rem 25 | rem Script has to be run by a DBA who has the privileges to 26 | rem view v$process, v$session, v$mystat 27 | rem 28 | rem Usage 29 | rem -- the notes assume the tablespace is not ASSM. 30 | rem execute dump_seg('tablex'); -- dump first data block 31 | rem execute dump_seg('tablex',5) -- dump first five data blocks 32 | rem execute dump_seg('indexy',1,'INDEX') -- dump root block of index 33 | rem execute dump_seg('tableX',i_start_block=>0 ) -- dump seg header block 34 | rem 35 | rem Various "optimizer" issues with 10g: 36 | rem select * from dba_extents 37 | rem where segment_name = 'T1' 38 | rem and extent_id = 0; 39 | rem vs. 40 | rem select * from dba_extents 41 | rem where segment_name = 'T1' 42 | rem order by extent_id; 43 | rem 44 | rem On one system, the first query crashed with error: 45 | rem ORA-00379: no free buffers available in buffer pool DEFAULT for block size 2K 46 | rem 47 | rem There had been an object in the 2K tablespace, 48 | rem which had been dropped but not purged. There 49 | rem were no buffers allocated to the 2K cache, 50 | rem hence the failure. And it was not possible 51 | rem to purge the recyclebin without creating the 52 | rem cache. 53 | rem 54 | rem Clearly, the join order had changed because of 55 | rem the extent_id predicate - and this led to the 56 | rem crash 57 | rem 58 | rem For this reason, I changed the code to query by 59 | rem segment and order by extent_id - stopping at the 60 | rem zero extent 61 | rem 62 | rem Performance can also be affected by how many extents 63 | rem you have, and whether you have collected statistics 64 | rem (in 10g) on the fixed tables - because of the call to 65 | rem check the extents in the segment headers. 66 | rem 67 | rem Internal enhancements in 11g 68 | rem You get a dump of all the copies in the buffer cache, 69 | rem and a copy of the version of the block on disc. 70 | rem 71 | 72 | start setenv 73 | 74 | create or replace procedure dump_seg( 75 | i_seg_name in varchar2, 76 | i_block_count in number default 1, 77 | i_seg_type in varchar2 default 'TABLE', 78 | i_start_block in number default 1, 79 | i_owner in varchar2 default sys_context('userenv','session_user'), 80 | i_partition_name in varchar2 default null, 81 | i_dump_formatted in boolean default true, 82 | i_dump_raw in boolean default false 83 | ) 84 | as 85 | m_file_id number; 86 | m_block_min number; 87 | m_block_max number; 88 | m_process varchar2(32); 89 | 90 | begin 91 | 92 | for r in ( 93 | select 94 | file_id, 95 | block_id + i_start_block block_min, 96 | block_id + i_start_block + i_block_count - 1 block_max 97 | from 98 | dba_extents 99 | where 100 | segment_name = upper(i_seg_name) 101 | and segment_type = upper(i_seg_type) 102 | and owner = upper(i_owner) 103 | and nvl(partition_name,'N/A') = upper(nvl(i_partition_name,'N/A')) 104 | order by 105 | extent_id 106 | ) loop 107 | 108 | m_file_id := r.file_id; 109 | m_block_min := r.block_min; 110 | m_block_max := r.block_max; 111 | exit; 112 | end loop; 113 | 114 | if (i_dump_formatted) then 115 | execute immediate 116 | 'alter session set events ''10289 trace name context off'''; 117 | 118 | execute immediate 119 | 'alter system dump datafile ' || m_file_id || 120 | ' block min ' || m_block_min || 121 | ' block max ' || m_block_max 122 | ; 123 | end if; 124 | 125 | if (i_dump_raw) then 126 | execute immediate 127 | 'alter session set events ''10289 trace name context forever'''; 128 | 129 | execute immediate 130 | 'alter system dump datafile ' || m_file_id || 131 | ' block min ' || m_block_min || 132 | ' block max ' || m_block_max 133 | ; 134 | 135 | end if; 136 | 137 | execute immediate 138 | 'alter session set events ''10289 trace name context off'''; 139 | 140 | -- 141 | -- For non-MTS, work out the trace file name 142 | -- 143 | 144 | select 145 | spid 146 | into 147 | m_process 148 | from 149 | v$session se, 150 | v$process pr 151 | where 152 | se.sid = (select sid from v$mystat where rownum = 1) 153 | and pr.addr = se.paddr 154 | ; 155 | 156 | dbms_output.new_line; 157 | dbms_output.put_line( 158 | 'Dumped ' || i_block_count || ' blocks from ' || 159 | i_seg_type || ' ' || i_seg_name || 160 | ' starting from block ' || i_start_block 161 | ); 162 | 163 | dbms_output.new_line; 164 | dbms_output.put_line('Trace file name includes: ' || m_process); 165 | 166 | dbms_output.new_line; 167 | 168 | exception 169 | when others then 170 | dbms_output.new_line; 171 | dbms_output.put_line('Unspecified error.'); 172 | dbms_output.put_line('Check syntax.'); 173 | dbms_output.put_line('dumpseg({segment_name},[{block count}],[{segment_type}]'); 174 | dbms_output.put_line(' [{start block (1)}],[{owner}],[{partition name}]'); 175 | dbms_output.put_line(' [{dump formatted YES/n}],[{dump raw y/NO}]'); 176 | dbms_output.new_line; 177 | raise; 178 | end; 179 | . 180 | / 181 | 182 | show errors 183 | 184 | drop public synonym dump_seg; 185 | create public synonym dump_seg for dump_seg; 186 | grant execute on dump_seg to public; 187 | -------------------------------------------------------------------------------- /ch_03/c_dump_tab.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_dump_tab.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: April 2011 5 | rem Purpose: Create a procedure to dump the first used block from a table 6 | rem 7 | rem Last tested 8 | rem 11.1.0.7 9 | rem Not tested 10 | rem 10.2.0.3 11 | rem 10.1.0.4 12 | rem 9.2.0.6 13 | rem 8.1.7.4 14 | rem 15 | rem Notes: 16 | rem Very simple-minded code to dump a block from a table 17 | rem by finding the block id of the "first" row in the table. 18 | rem 19 | rem Assumes by default the table owner is the calling user. 20 | rem Assumes the table is not partitioned. 21 | rem 22 | rem Select the rowid of the first row selectable, and convert 23 | rem to (relative) file and block number, and dump. 24 | rem 25 | 26 | start setenv 27 | 28 | create or replace procedure dump_table_block( 29 | i_tab_name in varchar2, 30 | i_owner in varchar2 default sys_context('userenv','session_user') 31 | ) 32 | as 33 | m_file_id number; 34 | m_block number; 35 | m_process varchar2(32); 36 | 37 | begin 38 | 39 | execute immediate 40 | ' select ' || 41 | ' dbms_rowid.rowid_relative_fno(rowid), ' || 42 | ' dbms_rowid.rowid_block_number(rowid) ' || 43 | ' from ' || 44 | i_owner || 45 | '.' || 46 | i_tab_name || 47 | ' where ' || 48 | ' rownum = 1 ' 49 | into 50 | m_file_id, m_block 51 | ; 52 | 53 | execute immediate 54 | 'alter system dump datafile ' || m_file_id || 55 | ' block ' || m_block 56 | ; 57 | 58 | -- 59 | -- For non-MTS, work out the trace file name 60 | -- 61 | 62 | select 63 | spid 64 | into 65 | m_process 66 | from 67 | v$session se, 68 | v$process pr 69 | where 70 | -- 71 | -- The first option is the 9.2 version for checking the SID 72 | -- The second is a quick and dirty option for 8.1.7 73 | -- provided SYS has made v$mystat visible (or this is the sys account) 74 | -- 75 | -- se.sid = (select dbms_support.mysid from dual) 76 | se.sid = (select sid from v$mystat where rownum = 1) 77 | and pr.addr = se.paddr 78 | ; 79 | 80 | dbms_output.new_line; 81 | dbms_output.put_line('Trace file name includes: ' || m_process); 82 | dbms_output.new_line; 83 | 84 | exception 85 | when others then 86 | dbms_output.new_line; 87 | dbms_output.put_line('Unspecified error.'); 88 | dbms_output.put_line('Check syntax.'); 89 | dbms_output.put_line('dump_table_block({table_name},[{owner}]'); 90 | dbms_output.new_line; 91 | raise; 92 | end; 93 | . 94 | / 95 | 96 | show errors 97 | 98 | drop public synonym dump_table_block; 99 | create public synonym dump_table_block for dump_table_block; 100 | grant execute on dump_table_block to public; 101 | -------------------------------------------------------------------------------- /ch_03/c_mystats.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_mystats.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Put names to v$mystat 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 10.2.0.3 10 | rem 10.1.0.4 11 | rem 9.2.0.8 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Should be run by SYS - which means it has to be re-run 16 | rem on a full database export/import 17 | 18 | rem 19 | rem Option 1 - using v$ 20 | rem Use first_rows and ordered to avoid a sort/merge join, and 21 | rem to allow faster elimination of the 'value = 0' rows. 22 | rem 23 | 24 | create or replace view v$my_stats 25 | as 26 | select 27 | /*+ 28 | first_rows 29 | ordered 30 | */ 31 | ms.sid, 32 | sn.statistic#, 33 | sn.name, 34 | sn.class, 35 | ms.value 36 | from 37 | v$mystat ms, 38 | v$statname sn 39 | where 40 | sn.statistic# = ms.statistic# 41 | ; 42 | 43 | rem 44 | rem Option 2 - using x$ 45 | rem Avoids the filter subquery for count(*) from x$ksusd 46 | rem (See v$fixed_view_definition) 47 | rem 48 | 49 | create or replace view v$my_stats 50 | as 51 | select 52 | /*+ 53 | first_rows 54 | ordered 55 | */ 56 | ms.ksusenum sid, 57 | sn.indx statistic#, 58 | sn.ksusdnam name, 59 | sn.ksusdcls class, 60 | ms.ksusestv value 61 | from 62 | x$ksumysta ms, 63 | x$ksusd sn 64 | where 65 | ms.inst_id = sys_context('userenv','instance') 66 | and bitand(ms.ksspaflg,1)!=0 67 | and bitand(ms.ksuseflg,1)!=0 68 | and sn.inst_id = sys_context('userenv','instance') 69 | and sn.indx = ms.ksusestn 70 | ; 71 | 72 | drop public synonym v$my_stats; 73 | create public synonym v$my_stats for v$my_stats; 74 | grant select on v$my_stats to public; 75 | -------------------------------------------------------------------------------- /ch_03/cleanout.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: cleanout.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: February 2003 5 | rem Purpose: Latching occurs on block cleanout but no gets are recorded 6 | rem 7 | rem Last tested 8 | rem 11.1.0.6 9 | rem 10.2.0.3 10 | rem 10.1.0.4 11 | rem 9.2.0.6 12 | rem 8.1.7.4 13 | rem 14 | rem Depends on 15 | rem c_mystats.sql 16 | rem snap_myst.sql 17 | rem snap_9_latch.sql (snap_11_latch.sql) 18 | rem snap_9_buffer.sql 19 | rem snap_9_kcbsw.sql (snap_11_kcbsw.sql) 20 | rem 21 | rem Notes: 22 | rem We create a table with one row per block and then 23 | rem update every block, forcing an indexed access to get 24 | rem all the blocks in the buffer. Note, commit cleanout 25 | rem applies only to a number of buffers limited by a 26 | rem percentage of the buffer size, and the buffers have to 27 | rem be in memory still. (A recent (10/2007) experiment on 10g 28 | rem suggested that the block could have been written, cleared 29 | rem from memory, and re-read by another process and still get 30 | rem a commit cleanout. 31 | rem 32 | rem On the commit we take a snapshot of session stats, 33 | rem buffer pool stats, and latches. The critical numbers 34 | rem are: 35 | rem session stats logical I/O (any type) 36 | rem commit cleanouts 37 | rem buffer pool logical I/O 38 | rem latches cache buffers chains latch 39 | rem 40 | rem 41 | rem My best result was: 42 | rem session logical reads 1 43 | rem commit cleanouts 180 44 | rem 45 | rem cache buffers chains 183 gets 46 | rem 47 | rem buffer pool 1 CU 48 | rem 49 | rem So we see no logical I/O recorded, but the latch 50 | rem activity suggests that we have hit the latch chain 51 | rem to clean the block. We can pursue this further to 52 | rem the v$latch_children to show that the bulk of the 53 | rem latching was one latch access per child - covering 54 | rem all the blocks in the table. 55 | rem 56 | rem For cleanest numbers, run the script twice so that 57 | rem the cost of loading the snapshot code doesn't obscure 58 | rem the figures. 59 | rem 60 | rem A snapshot of kcbsw shows very few calls as well - 61 | rem largely related to the undo segments 62 | rem 63 | rem Results from 11.1.0.6 - with 500 blocks which all stayed 64 | rem in the cache, I got 500 cleanouts reported but only 13 65 | rem session logical I/Os (one was the db block get for the 66 | rem transaction table update, of course). 67 | rem 68 | rem With a "flush buffer cache", though, I only got 100 69 | rem attempts and 100 failures. 70 | rem 71 | 72 | start setenv 73 | 74 | drop table t1; 75 | 76 | create table t1 ( 77 | id number, 78 | small_no number(5,2), 79 | small_vc varchar2(10), 80 | padding varchar2(1000), 81 | constraint t1_pk primary key (id) 82 | ) 83 | pctfree 90 84 | pctused 10 85 | ; 86 | 87 | insert into t1 88 | select 89 | rownum, 90 | 1+ trunc(rownum/10), 91 | lpad(rownum,10), 92 | rpad('x',1000) 93 | from 94 | all_objects 95 | where 96 | rownum <= 500 97 | ; 98 | 99 | commit; 100 | 101 | select small_no from t1 102 | where small_no < 0; 103 | 104 | update /*+ index(t1) */ t1 105 | set 106 | small_vc = small_vc + 1 107 | ; 108 | 109 | -- 110 | -- Do this to see commit cleanout failures 111 | -- 112 | 113 | alter system flush buffer_cache; 114 | 115 | execute snap_latch.start_snap 116 | execute snap_buffer.start_snap 117 | execute snap_my_stats.start_snap 118 | execute snap_kcbsw.start_snap 119 | 120 | commit; 121 | 122 | spool cleanout 123 | 124 | execute snap_kcbsw.end_snap -- no useful results from 11g 125 | execute snap_my_stats.end_snap 126 | execute snap_buffer.end_snap 127 | execute snap_latch.end_snap(10) 128 | 129 | spool off 130 | -------------------------------------------------------------------------------- /ch_03/core_03_ct.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_03_ct.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: Apr 2011 5 | rem Purpose: 6 | rem 7 | rem Last tested 8 | rem 11.1.0.7 9 | rem Not tested 10 | rem 11.2.0.2 11 | rem 10.2.0.3 12 | rem 9.2.0.8 13 | rem 8.1.7.4 14 | rem 15 | rem Depends on 16 | rem c_dump_tab.sql 17 | rem 18 | rem Notes: 19 | rem Create a simple table with 4 rows for updates from three sessions 20 | rem 21 | 22 | start setenv 23 | 24 | drop table t1; 25 | 26 | create table t1(id number, n1 number); 27 | 28 | insert into t1 values(1,1); 29 | insert into t1 values(2,2); 30 | insert into t1 values(3,3); 31 | 32 | commit; 33 | 34 | create unique index t1_i1 on t1(id); 35 | 36 | begin 37 | dbms_stats.gather_table_stats( 38 | ownname => user, 39 | tabname =>'T1', 40 | estimate_percent => 100, 41 | method_opt => 'for all columns size 1' 42 | ); 43 | end; 44 | / 45 | 46 | -- 47 | -- For 11g - force to disc for the dump 48 | -- 49 | 50 | alter system checkpoint; 51 | 52 | -- 53 | -- Now dump the first findable block of the table 54 | -- 55 | 56 | execute dump_table_block('t1') 57 | 58 | 59 | set doc off 60 | doc 61 | 62 | # 63 | 64 | -------------------------------------------------------------------------------- /ch_03/core_cleanout.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_cleanout.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: February 2003 5 | rem Purpose: Latching occurs on block cleanout but no gets are recorded 6 | rem 7 | rem Last tested 8 | rem 11.1.0.6 9 | rem 10.2.0.3 10 | rem 10.1.0.4 11 | rem 9.2.0.8 12 | rem 8.1.7.4 13 | rem 14 | rem Depends on 15 | rem c_mystats.sql 16 | rem snap_myst.sql 17 | rem snap_9_latch.sql (snap_11_latch.sql) 18 | rem snap_9_buffer.sql 19 | rem snap_9_kcbsw.sql (snap_11_kcbsw.sql) 20 | rem 21 | rem Notes: 22 | rem We create a table with one row per block and then 23 | rem update every block, forcing an indexed access to get 24 | rem all the blocks in the buffer. Note, commit cleanout 25 | rem applies only to a number of buffers limited by a 26 | rem percentage of the buffer size, and the buffers have to 27 | rem be in memory still. (A recent (10/2007) experiment on 10g 28 | rem suggested that the block could have been written, cleared 29 | rem from memory, and re-read by another process and still get 30 | rem a commit cleanout. 31 | rem 32 | rem On the commit we take a snapshot of session stats, 33 | rem buffer pool stats, and latches. The critical numbers 34 | rem are: 35 | rem session stats logical I/O (any type) 36 | rem commit cleanouts 37 | rem buffer pool logical I/O 38 | rem latches cache buffers chains latch 39 | rem 40 | rem 41 | rem My best result was: 42 | rem session logical reads 1 43 | rem commit cleanouts 180 44 | rem 45 | rem cache buffers chains 183 gets 46 | rem 47 | rem buffer pool 1 CU 48 | rem 49 | rem So we see no logical I/O recorded, but the latch 50 | rem activity suggests that we have hit the latch chain 51 | rem to clean the block. We can pursue this further to 52 | rem the v$latch_children to show that the bulk of the 53 | rem latching was one latch access per child - covering 54 | rem all the blocks in the table. 55 | rem 56 | rem For cleanest numbers, run the script twice so that 57 | rem the cost of loading the snapshot code doesn't obscure 58 | rem the figures. 59 | rem 60 | rem A snapshot of kcbsw shows very few calls as well - 61 | rem largely related to the undo segments 62 | rem 63 | rem Results from 11.1.0.6 - with 500 blocks which all stayed 64 | rem in the cache, I got 500 cleanouts reported but only 13 65 | rem session logical I/Os (one was the db block get for the 66 | rem transaction table update, of course). 67 | rem 68 | rem With a "flush buffer cache", though, I only got 100 69 | rem attempts and 100 failures. 70 | rem 71 | 72 | start setenv 73 | 74 | drop table t1; 75 | 76 | create table t1 ( 77 | id number, 78 | small_no number(5,2), 79 | small_vc varchar2(10), 80 | padding varchar2(1000), 81 | constraint t1_pk primary key (id) 82 | ) 83 | pctfree 90 84 | pctused 10 85 | ; 86 | 87 | insert into t1 88 | select 89 | rownum, 90 | 1+ trunc(rownum/10), 91 | lpad(rownum,10), 92 | rpad('x',1000) 93 | from 94 | all_objects 95 | where 96 | rownum <= 500 97 | ; 98 | 99 | commit; 100 | 101 | begin 102 | dbms_stats.gather_table_stats( 103 | ownname => user, 104 | tabname =>'T1', 105 | estimate_percent => 100, 106 | method_opt => 'for all columns size 1' 107 | ); 108 | end; 109 | / 110 | 111 | select 112 | small_no 113 | from 114 | t1 115 | where 116 | small_no < 0 117 | ; 118 | 119 | update /*+ index(t1) */ t1 120 | set 121 | small_vc = small_vc + 1 122 | ; 123 | 124 | -- 125 | -- Do this to see commit cleanout failures 126 | -- 127 | 128 | alter system flush buffer_cache; 129 | 130 | execute snap_latch.start_snap 131 | execute snap_buffer.start_snap 132 | execute snap_my_stats.start_snap 133 | execute snap_kcbsw.start_snap 134 | 135 | commit; 136 | 137 | spool core_cleanout 138 | 139 | execute snap_kcbsw.end_snap 140 | execute snap_my_stats.end_snap 141 | execute snap_buffer.end_snap 142 | execute snap_latch.end_snap(10) 143 | 144 | set autotrace traceonly explain 145 | select /*+ full(t1) */ count(*) from t1; 146 | set autotrace off 147 | 148 | alter system switch logfile; 149 | 150 | prompt ======================= 151 | prompt First Tablescan results 152 | prompt ======================= 153 | 154 | execute snap_kcbsw.start_snap 155 | execute snap_my_stats.start_snap 156 | 157 | select /*+ full(t1) */ count(*) from t1; 158 | 159 | execute snap_my_stats.end_snap 160 | execute snap_kcbsw.end_snap 161 | 162 | select 163 | objd, count(*) 164 | from 165 | v$bh 166 | where 167 | dirty = 'Y' 168 | group by 169 | objd 170 | order by 171 | count(*) 172 | ; 173 | 174 | 175 | prompt ===================================== 176 | prompt Sleeping 7 sescnds for redo log flush 177 | prompt ===================================== 178 | 179 | execute dbms_lock.sleep(7) 180 | execute dump_log 181 | 182 | prompt ======================== 183 | prompt Second Tablescan results 184 | prompt ======================== 185 | 186 | execute snap_kcbsw.start_snap 187 | execute snap_my_stats.start_snap 188 | 189 | select /*+ full(t1) */ count(*) from t1; 190 | 191 | execute snap_my_stats.end_snap 192 | execute snap_kcbsw.end_snap 193 | 194 | 195 | spool off 196 | 197 | set doc off 198 | doc 199 | 200 | 11.1.0.6 results on final tablescan - plus redo record 201 | ------------------------------------------------------ 202 | Name Value 203 | ---- ----- 204 | session logical reads 1,012 205 | consistent gets 1,012 206 | consistent gets from cache 1,012 207 | consistent gets from cache (fastpath) 501 208 | consistent gets - examination 506 209 | physical reads 504 210 | physical reads cache 504 211 | db block changes 500 212 | free buffer requested 504 213 | calls to kcmgrs 500 214 | calls to get snapshot scn: kcmgss 7 215 | redo entries 500 216 | redo size 36,000 217 | redo subscn max counts 500 218 | no work - consistent read gets 3 219 | cleanouts only - consistent read gets 500 220 | immediate (CR) block cleanout applications 500 221 | commit txn count during cleanout 500 222 | cleanout - number of ktugct calls 500 223 | 224 | REDO RECORD - Thread:1 RBA: 0x00092b.0000004c.0138 LEN: 0x0048 VLD: 0x01 225 | SCN: 0x0000.01779daf SUBSCN: 1 04/30/2011 11:04:59 226 | CHANGE #1 TYP:0 CLS: 1 AFN:3 DBA:0x00c02cfb OBJ:99196 SCN:0x0000.01779da6 SEQ: 1 OP:4.1 227 | Block cleanout record, scn: 0x0000.01779daf ver: 0x01 opt: 0x01, entries follow... 228 | itli: 2 flg: 2 scn: 0x0000.01779daa 229 | 230 | 231 | 232 | 233 | 234 | 10.2.0.3 results 235 | ---------------- 236 | Name Value 237 | ---- ----- 238 | session logical reads 1,012 239 | consistent gets 1,012 240 | consistent gets from cache 1,012 241 | consistent gets - examination 506 242 | physical reads 504 243 | db block changes 500 244 | free buffer requested 504 245 | calls to get snapshot scn: kcmgss 7 246 | redo entries 500 247 | redo size 36,044 248 | redo subscn max counts 500 249 | no work - consistent read gets 3 250 | cleanouts only - consistent read gets 500 251 | immediate (CR) block cleanout applications 500 252 | commit txn count during cleanout 500 253 | cleanout - number of ktugct calls 500 254 | 255 | REDO RECORD - Thread:1 RBA: 0x000106.00000002.01a4 LEN: 0x0048 VLD: 0x01 256 | SCN: 0x0000.0405da78 SUBSCN: 1 04/30/2011 11:17:23 257 | CHANGE #1 TYP:0 CLS: 1 AFN:5 DBA:0x0140eb8f OBJ:78338 SCN:0x0000.0405da6b SEQ: 1 OP:4.1 258 | Block cleanout record, scn: 0x0000.0405da78 ver: 0x01 opt: 0x01, entries follow... 259 | itli: 2 flg: 2 scn: 0x0000.0405da73 260 | 261 | # 262 | -------------------------------------------------------------------------------- /ch_03/core_cleanout_2.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_cleanout_2.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: February 2003 5 | rem Purpose: 6 | rem 7 | rem Last tested 8 | rem 11.1.0.6 9 | rem 10.2.0.1 10 | rem 10.1.0.4 11 | rem 9.2.0.6 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Commit cleanout makes clean block dirty 16 | rem 17 | rem Privileges required 18 | rem select on v$bh 19 | rem 20 | 21 | start setenv 22 | 23 | drop table t1; 24 | 25 | create table t1 ( 26 | id number, 27 | small_no number(5,2), 28 | small_vc varchar2(10), 29 | padding varchar2(1000), 30 | constraint t1_pk primary key (id) 31 | ) 32 | pctfree 90 33 | pctused 10 34 | ; 35 | 36 | insert into t1 37 | select 38 | rownum, 39 | 1+ trunc(rownum/10), 40 | lpad(rownum,10), 41 | rpad('x',1000) 42 | from 43 | all_objects 44 | where 45 | rownum <= 500 46 | ; 47 | 48 | commit; 49 | 50 | begin 51 | dbms_stats.gather_table_stats( 52 | ownname => user, 53 | tabname =>'T1', 54 | estimate_percent => 100, 55 | method_opt => 'for all columns size 1' 56 | ); 57 | end; 58 | / 59 | 60 | select 61 | small_no 62 | from 63 | t1 64 | where 65 | small_no < 0 66 | ; 67 | 68 | update /*+ index(t1) */ t1 69 | set 70 | small_vc = small_vc + 1 71 | ; 72 | 73 | spool core_cleanout_2 74 | 75 | -- 76 | -- Check number of dirty buffers after update 77 | -- 78 | 79 | select 80 | objd, count(*) 81 | from 82 | v$bh 83 | where 84 | dirty = 'Y' 85 | group by 86 | objd 87 | order by 88 | count(*) 89 | ; 90 | 91 | alter system checkpoint; 92 | alter system checkpoint; 93 | 94 | -- 95 | -- Check number of dirty buffers after checkpoint 96 | -- 97 | 98 | select 99 | objd, count(*) 100 | from 101 | v$bh 102 | where 103 | dirty = 'Y' 104 | group by 105 | objd 106 | order by 107 | count(*) 108 | ; 109 | 110 | 111 | commit; 112 | 113 | -- 114 | -- Check number of dirty buffers after commit cleanout 115 | -- 116 | 117 | select 118 | objd, count(*) 119 | from 120 | v$bh 121 | where 122 | dirty = 'Y' 123 | group by 124 | objd 125 | order by 126 | count(*) 127 | ; 128 | 129 | 130 | 131 | 132 | spool off 133 | -------------------------------------------------------------------------------- /ch_03/core_cleanout_3.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_cleanout_3.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: February 2003 5 | rem Purpose: 6 | rem 7 | rem Last tested 8 | rem 11.1.0.6 9 | rem 10.2.0.1 10 | rem 10.1.0.4 11 | rem 9.2.0.6 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Parallel query (serial direct path) don't do delayed block cleanout. 16 | rem 17 | rem Depends on 18 | rem snap_stat.sql 19 | rem 20 | 21 | start setenv 22 | 23 | drop table t1; 24 | 25 | create table t1 ( 26 | id number, 27 | small_no number(5,2), 28 | small_vc varchar2(10), 29 | padding varchar2(1000), 30 | constraint t1_pk primary key (id) 31 | ) 32 | pctfree 90 33 | pctused 10 34 | ; 35 | 36 | insert into t1 37 | select 38 | rownum, 39 | 1+ trunc(rownum/10), 40 | lpad(rownum,10), 41 | rpad('x',1000) 42 | from 43 | all_objects 44 | where 45 | rownum <= 500 46 | ; 47 | 48 | commit; 49 | 50 | begin 51 | dbms_stats.gather_table_stats( 52 | ownname => user, 53 | tabname =>'T1', 54 | estimate_percent => 100, 55 | method_opt => 'for all columns size 1' 56 | ); 57 | end; 58 | / 59 | 60 | select 61 | small_no 62 | from 63 | t1 64 | where 65 | small_no < 0 66 | ; 67 | 68 | update /*+ index(t1) */ t1 69 | set 70 | small_vc = small_vc + 1 71 | ; 72 | 73 | spool core_cleanout_3 74 | 75 | alter system flush buffer_cache; 76 | commit; 77 | 78 | execute snap_stats.start_snap 79 | 80 | select 81 | /*+ parallel(t1 2) full(t1) */ 82 | count(*) 83 | from 84 | t1 85 | ; 86 | 87 | execute snap_stats.end_snap 88 | 89 | execute snap_stats.start_snap 90 | 91 | select 92 | /*+ parallel(t1 2) full(t1) */ 93 | count(*) 94 | from 95 | t1 96 | ; 97 | 98 | execute snap_stats.end_snap 99 | 100 | execute snap_stats.start_snap 101 | 102 | select 103 | /*+ parallel(t1 2) full(t1) */ 104 | count(*) 105 | from 106 | t1 107 | ; 108 | 109 | execute snap_stats.end_snap 110 | 111 | 112 | spool off 113 | -------------------------------------------------------------------------------- /ch_03/core_cleanout_4.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: core_cleanout_4.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: February 2003 5 | rem Purpose: 6 | rem 7 | rem Last tested 8 | rem 11.1.0.6 9 | rem 10.2.0.1 10 | rem 10.1.0.4 11 | rem 9.2.0.6 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Transaction Table consistent reads 16 | rem 17 | rem Privileges needed 18 | rem alter system 19 | rem Execute on 20 | rem dbms_lock 21 | rem dbms_stats 22 | rem dbms_cdc_utility 23 | rem 24 | rem Depends on 25 | rem c_mystats.sql 26 | rem snap_myst.sql 27 | rem snap_rollstat.sql 28 | rem c_dump_seg.sql 29 | rem 30 | 31 | start setenv 32 | 33 | drop table t2; 34 | drop table t1; 35 | 36 | create table t1 ( 37 | id number, 38 | small_no number(5,2), 39 | small_vc varchar2(10), 40 | padding varchar2(1000), 41 | constraint t1_pk primary key (id) 42 | ) 43 | pctfree 90 44 | pctused 10 45 | ; 46 | 47 | insert into t1 48 | select 49 | rownum, 50 | 1+ trunc(rownum/10), 51 | lpad(rownum,10), 52 | rpad('x',1000) 53 | from 54 | all_objects 55 | where 56 | rownum <= 500 57 | ; 58 | 59 | create table t2 ( n1 number); 60 | insert into t2 values (0); 61 | commit; 62 | 63 | begin 64 | dbms_stats.gather_table_stats( 65 | ownname => user, 66 | tabname =>'T1', 67 | estimate_percent => 100, 68 | method_opt => 'for all columns size 1' 69 | ); 70 | dbms_stats.gather_table_stats( 71 | ownname => user, 72 | tabname =>'T2', 73 | estimate_percent => 100, 74 | method_opt => 'for all columns size 1' 75 | ); 76 | end; 77 | / 78 | 79 | select 80 | small_no 81 | from 82 | t1 83 | where 84 | small_no < 0 85 | ; 86 | 87 | update 88 | /*+ index(t1) */ 89 | t1 90 | set 91 | small_vc = small_vc + 1 92 | ; 93 | 94 | alter system checkpoint; 95 | alter system flush buffer_cache; 96 | 97 | execute dbms_lock.sleep(2) 98 | 99 | execute dump_seg('t1') 100 | 101 | alter system checkpoint; 102 | alter system flush buffer_cache; 103 | 104 | commit; 105 | 106 | spool core_cleanout_4 107 | 108 | select 109 | sys.dbms_cdc_utility.get_current_scn post_commit_scn 110 | from 111 | dual 112 | ; 113 | 114 | -- 115 | -- First test, comment out the "set transaction read only" 116 | -- Run the whole code path from a single session. 117 | -- 118 | -- Second test, comment out the "set transaction read only" 119 | -- comment out the snapshot and pl/sql loop from this session 120 | -- and run them from another session before pressing return. 121 | -- 122 | -- Third test, run the snapshot and loop from a second session 123 | -- as for the second test, but allow the set transaction to 124 | -- run in this session first. 125 | -- 126 | 127 | -- set transaction read only; 128 | 129 | pause Press return to continue 130 | 131 | execute snap_rollstats.start_snap 132 | 133 | begin 134 | for i in 1..17000 loop 135 | update t2 set n1 = i; 136 | commit; 137 | end loop; 138 | end; 139 | / 140 | 141 | execute snap_rollstats.end_snap 142 | 143 | select 144 | sys.dbms_cdc_utility.get_current_scn after_batch_scn 145 | from 146 | dual 147 | ; 148 | 149 | execute snap_my_stats.start_snap 150 | 151 | select 152 | /*+ full(t1) */ 153 | count(*) 154 | from 155 | t1 156 | ; 157 | 158 | execute snap_my_stats.end_snap 159 | 160 | select 161 | ora_rowscn, count(*) 162 | from 163 | t1 164 | group by 165 | ora_rowscn 166 | order by 167 | count(*) 168 | ; 169 | 170 | spool off 171 | -------------------------------------------------------------------------------- /ch_03/setenv.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: setenv.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: June 2002 5 | rem Purpose: Set up various SQL*Plus formatting commands. 6 | rem 7 | rem Notes: 8 | rem 9 | 10 | set pause off 11 | 12 | rem 13 | rem If you want to call dbms_xplan.display_cursor() to get the 14 | rem place for the last statement you executed you will have to 15 | rem set serveroutput off 16 | rem 17 | 18 | set serveroutput on size 1000000 format wrapped 19 | 20 | rem 21 | rem I'd like to enable java output, but it seems 22 | rem to push the UGA up by about 4MB when I do it 23 | rem 24 | 25 | rem execute dbms_java.set_output(1000000) 26 | 27 | rem 28 | rem Reminder about DOC, and using the # to end DOC 29 | rem the SET command stops doc material from appearing 30 | rem 31 | 32 | execute dbms_random.seed(0) 33 | 34 | set doc off 35 | doc 36 | 37 | end doc is marked with # 38 | 39 | # 40 | 41 | set linesize 120 42 | set trimspool on 43 | set pagesize 24 44 | set arraysize 25 45 | 46 | -- set longchunksize 32768 47 | -- set long 32768 48 | 49 | set autotrace off 50 | 51 | clear breaks 52 | ttitle off 53 | btitle off 54 | 55 | column owner format a15 56 | column segment_name format a20 57 | column table_name format a20 58 | column index_name format a20 59 | column object_name format a20 60 | column subobject_name format a20 61 | column partition_name format a20 62 | column subpartition_name format a20 63 | column column_name format a20 64 | column column_expression format a40 word wrap 65 | column constraint_name format a20 66 | 67 | column referenced_name format a30 68 | 69 | column file_name format a60 70 | 71 | column low_value format a24 72 | column high_value format a24 73 | 74 | column parent_id_plus_exp format 999 75 | column id_plus_exp format 990 76 | column plan_plus_exp format a90 77 | column object_node_plus_exp format a14 78 | column other_plus_exp format a90 79 | column other_tag_plus_exp format a29 80 | 81 | column access_predicates format a80 82 | column filter_predicates format a80 83 | column projection format a80 84 | column remarks format a80 85 | column partition_start format a12 86 | column partition_stop format a12 87 | column partition_id format 999 88 | column other_tag format a32 89 | column object_alias format a24 90 | 91 | column object_node format a13 92 | column other format a150 93 | 94 | column os_username format a30 95 | column terminal format a24 96 | column userhost format a24 97 | column client_id format a24 98 | 99 | column statistic_name format a35 100 | 101 | column namespace format a20 102 | column attribute format a20 103 | 104 | column hint format a40 105 | 106 | column start_time format a25 107 | column end_time format a25 108 | 109 | column time_now noprint new_value m_timestamp 110 | 111 | set feedback off 112 | 113 | select to_char(sysdate,'hh24miss') time_now from dual; 114 | commit; 115 | 116 | set feedback on 117 | 118 | set timing off 119 | set verify off 120 | 121 | alter session set optimizer_mode = all_rows; 122 | 123 | spool log 124 | 125 | -------------------------------------------------------------------------------- /ch_03/snap_11_kcbsw.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_11_kcbsw.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2008 5 | rem Purpose: Package to get snapshot start and delta of cache usage 6 | rem 7 | rem Notes 8 | rem In 11g, the 'other_wait' is the only thing in x$kcbsw 9 | rem the other columns are in x$kcbuwhy. And we don't record 10 | rem all the buffer gets any more! 11 | rem 12 | rem 8.1.7.4 has 458 routines listed in x$kcbsw 13 | rem 9.2.0.3 has 675 14 | rem 9.2.0.6 has 677 15 | rem 9.2.0.6 has 694 16 | rem 10.1.0.1 has 773 17 | rem 10.1.0.4 has 782 18 | rem 10.2.0.1 has 802 19 | rem 10.2.0.3 has 806 20 | rem 11.1.0.6 has 1,050 21 | rem 22 | rem Some actions seem to change their choice of call as 23 | rem you go through different versions of Oracle - so 24 | rem perhaps many of the calls are there for historical 25 | rem reasons and 'just in case'. 26 | rem 27 | rem Has to be run by SYS to create the package 28 | rem According to a note on RAC, 29 | rem WHY2 is 'waits' 30 | rem OTHER_WAITS is 'caused waits' 31 | rem 32 | rem Usage: 33 | rem set serveroutput on size 1000000 format wrapped 34 | rem set linesize 120 35 | rem set trimspool on 36 | rem execute snap_kcbsw.start_snap 37 | rem -- do something 38 | rem execute snap_kcbsw.end_snap 39 | rem 40 | rem kdiwh15: kdifxs Index FULL / RANGE scan (?? leaf ??) 41 | rem kdiwh16: kdifxs Index unique scan scan (?? leaf ??) 42 | rem kdiwh17: kdifind Branch in CU mode 43 | rem kdiwh18: kdifind Branch for update 44 | rem 45 | rem ktuwh27: kturbk Acquiring undo records for rolling back. 46 | rem 47 | rem kduwh01: kdusru Single row-piece update 48 | rem 49 | rem ktuwh03: ktugnb Rollback segment header update for next undo block ?? 50 | rem ktuwh01: ktugus Rollback segment header ?? 51 | rem ktuwh02: ktugus Rollback segment header acquire for commit ?? 52 | rem 53 | rem ktuwh20: ktuabt Updating rollback segment headers on rollback ?? 54 | rem ktuwh23: ktubko Reading rollback records to apply ?? 55 | rem ktuwh24: ktubko Reading rollback blocks to apply ?? 56 | rem kdowh00: kdoiur Applying rollback records to data blocks ?? 57 | rem 58 | rem ktuwh05: ktugct Acquiring undo segment header to get control table 59 | rem 60 | rem ktswh39: ktsrsp Space management ?? Block on free list ? 61 | rem 62 | rem kddwh01: kdddel Delete row 63 | rem 64 | rem Simple update using a one block tablescan and no indexes 65 | rem -------------------------------------------------------- 66 | rem 1 ktuwh01: ktugus -- undo segment header 67 | rem 1 ktewh25: kteinicnt 68 | rem 1 ktewh26: kteinpscan 69 | rem 1 kdswh01: kdstgr -- tablescan get row 70 | rem 1 kduwh01: kdusru -- single row-piece update 71 | rem 72 | rem 100 index fast full scans for count(*) 73 | rem -------------------------------------- 74 | rem 200 ktewh26: kteinpscan 75 | rem 1,000 ktewh27: kteinmap 76 | rem 143,300 kdiwh100: kdircys 77 | rem 78 | rem 10,000 queries into secondary index of IOT followed by IOT block guess 79 | rem ---------------------------------------------------------------------- 80 | rem 10,015 kdiwh08: kdiixs -- range scan leaf ? 81 | rem 10,015 kdiwh09: kdiixs -- range scan branch ? 82 | rem 10,000 kdiwh68: kdifbk -- jump to guessed block ? 83 | rem 84 | rem 10,000 select single row by rowid. 85 | rem ---------------------------------- 86 | rem 10,000 kdswh05: kdsgrp -- table block by rowid 87 | rem 88 | rem 10,000 select single row by PK - with BLEVEL = 2 (non-unique index ?) 89 | rem --------------------------------------------------------------------- 90 | rem 10,000 kdswh05: kdsgrp -- table block by rowid 91 | rem 10,006 kdiwh08: kdiixs -- leaf block 92 | rem 20,006 kdiwh09: kdiixs -- branch block 93 | rem 94 | rem 100 tablescans for count(*) 95 | rem --------------------------- 96 | rem 100 ktewh25: kteinicnt 97 | rem 100 ktewh26: kteinpscan 98 | rem 100 ktewh27: kteinmap 99 | rem 28,600 kdswh01: kdstgr 100 | rem 101 | rem 20,000 unique scan on a compressed index to get row 102 | rem --------------------------------------------------- 103 | rem 20,000 kdswh02: kdsgrp -- gets - examination (table) 104 | rem 20,000 kdiwh06: kdifbk -- gets - examination (leaf) 105 | rem 20,000 kdiwh07: kdifbk -- gets - examination (branch) 106 | rem 107 | rem 20,000 RI checks against height = 1 index plus 108 | rem 20,000 RI checks against height = 2 index 109 | rem --------------------------------------------------- 110 | rem 40,000 kdiwh17: kdifind Current mode seek on branch ? 111 | rem 20,000 kdiwh22: kdifind Current mode seek on leaf 112 | rem 113 | rem 10,000 inserts into empty table 114 | rem ------------------------------- 115 | rem 10,007 kdiwh17: kdifind Current mode seek on branch ? 116 | rem 580 kdiwh18: kdifind Current mode on branch ? 117 | rem 9,427 kdiwh22: kdifind Current mode on leaf ? 118 | rem 119 | rem 10,000 nested loop into single table hash cluster 120 | rem ------------------------------------------------- 121 | rem 10,000 kdswh04: kdscgr (10,000 examinations) 122 | rem 123 | rem Possibly associated with index coalesce 124 | rem --------------------------------------- 125 | rem 27 kdiwh154: kdi2merge 126 | rem 22 kdiwh155: kdi2merge 127 | rem 22 kdiwh156: kdi2merge 128 | rem 20 kdiwh157: kdi2merge 129 | rem 130 | rem FK index check on delete from parent (1M child rows, 2491 leafs exist) 131 | rem ---------------------------------------------------------------------- 132 | rem 1 kdiwh24: kdiexi 133 | rem 1 kdiwh25: kdiexi 134 | rem 2,489 kdiwh26: kdiexi 135 | rem 136 | rem Buffer Busy Waits: 137 | rem ------------------ 138 | rem The OTHER_WAIT column sums (very nearly) to the total of v$waitstat. 139 | rem (see Metalink note 34405.1) 140 | rem For example, when waiting because of a discrete transaction, we saw 141 | rem "kduwh01: kdusru" incrementing at the same rate as 142 | rem "data block" in v$waitstat (NB not undo block). 143 | rem 144 | 145 | create or replace package snap_kcbsw as 146 | procedure start_snap; 147 | procedure end_snap(i_limit in number default 0); 148 | end; 149 | / 150 | 151 | create or replace package body snap_kcbsw as 152 | 153 | cursor c1 is 154 | select 155 | indx, 156 | why0, 157 | why1, 158 | why2 159 | from 160 | x$kcbuwhy 161 | ; 162 | 163 | type w_type1 is table of c1%rowtype index by binary_integer; 164 | w_list1 w_type1; 165 | empty_list w_type1; 166 | 167 | w_sum1 c1%rowtype; 168 | w_count number(6); 169 | 170 | cursor c2(i_task number) is 171 | select 172 | kcbwhdes 173 | from x$kcbwh 174 | where 175 | indx = i_task 176 | ; 177 | 178 | r2 c2%rowtype; 179 | 180 | m_start_time date; 181 | m_start_flag char(1); 182 | m_end_time date; 183 | 184 | procedure start_snap is 185 | begin 186 | 187 | m_start_time := sysdate; 188 | m_start_flag := 'U'; 189 | w_list1 := empty_list; 190 | 191 | for r in c1 loop 192 | w_list1(r.indx).why0 := r.why0; 193 | w_list1(r.indx).why1 := r.why1; 194 | w_list1(r.indx).why2 := r.why2; 195 | end loop; 196 | 197 | end start_snap; 198 | 199 | 200 | procedure end_snap(i_limit in number default 0) is 201 | begin 202 | 203 | m_end_time := sysdate; 204 | 205 | dbms_output.put_line('---------------------------------'); 206 | dbms_output.put_line('Buffer Cache - ' || 207 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 208 | ); 209 | 210 | if m_start_flag = 'U' then 211 | dbms_output.put_line('Interval:- ' || 212 | trunc(86400 * (m_end_time - m_start_time)) || 213 | ' seconds' 214 | ); 215 | else 216 | dbms_output.put_line('Since Startup:- ' || 217 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 218 | ); 219 | end if; 220 | 221 | if (i_limit != 0) then 222 | dbms_output.put_line('Lower limit:- ' || i_limit); 223 | end if; 224 | 225 | dbms_output.put_line('---------------------------------'); 226 | 227 | 228 | dbms_output.put_line( 229 | lpad('Why0',14) || 230 | lpad('Why1',14) || 231 | lpad('Why2',14) 232 | ); 233 | 234 | dbms_output.put_line( 235 | lpad('----',14) || 236 | lpad('----',14) || 237 | lpad('----',14) 238 | ); 239 | 240 | w_sum1.why0 := 0; 241 | w_sum1.why1 := 0; 242 | w_sum1.why2 := 0; 243 | w_count := 0; 244 | 245 | for r in c1 loop 246 | if (not w_list1.exists(r.indx)) then 247 | w_list1(r.indx).why0 := 0; 248 | w_list1(r.indx).why1 := 0; 249 | w_list1(r.indx).why2 := 0; 250 | end if; 251 | 252 | if ( 253 | r.why0 > w_list1(r.indx).why0 + i_limit 254 | or r.why1 > w_list1(r.indx).why1 + i_limit 255 | or r.why2 > w_list1(r.indx).why2 + i_limit 256 | ) then 257 | 258 | dbms_output.put(to_char( 259 | r.why0 - w_list1(r.indx).why0, 260 | '9,999,999,990') 261 | ); 262 | dbms_output.put(to_char( 263 | r.why1 - w_list1(r.indx).why1, 264 | '9,999,999,990') 265 | ); 266 | dbms_output.put(to_char( 267 | r.why2 - w_list1(r.indx).why2, 268 | '9,999,999,990') 269 | ); 270 | 271 | open c2 (r.indx); 272 | fetch c2 into r2; 273 | close c2; 274 | dbms_output.put(' '|| r2.kcbwhdes); 275 | 276 | dbms_output.new_line; 277 | 278 | w_sum1.why0 := w_sum1.why0 + r.why0 - w_list1(r.indx).why0; 279 | w_sum1.why1 := w_sum1.why1 + r.why1 - w_list1(r.indx).why1; 280 | w_sum1.why2 := w_sum1.why2 + r.why2 - w_list1(r.indx).why2; 281 | w_count := w_count + 1; 282 | 283 | end if; 284 | 285 | end loop; 286 | 287 | dbms_output.put_line( 288 | lpad('----',14) || 289 | lpad('----',14) || 290 | lpad('----',14) 291 | ); 292 | 293 | dbms_output.put(to_char(w_sum1.why0,'9,999,999,990')); 294 | dbms_output.put(to_char(w_sum1.why1,'9,999,999,990')); 295 | dbms_output.put(to_char(w_sum1.why2,'9,999,999,990')); 296 | dbms_output.put(' Total: ' || w_count || ' rows'); 297 | dbms_output.new_line; 298 | 299 | end end_snap; 300 | 301 | begin 302 | select 303 | startup_time, 'S' 304 | into 305 | m_start_time, m_start_flag 306 | from 307 | v$instance 308 | ; 309 | 310 | end snap_kcbsw; 311 | / 312 | 313 | 314 | drop public synonym snap_kcbsw; 315 | create public synonym snap_kcbsw for snap_kcbsw; 316 | grant execute on snap_kcbsw to public; 317 | -------------------------------------------------------------------------------- /ch_03/snap_9_buffer.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_buffer.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$buffer_pool_statistics 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 180 13 | rem set trimspool on 14 | rem execute snap_buffer.start_snap 15 | rem -- do something 16 | rem execute snap_buffer.end_snap 17 | rem 18 | 19 | create or replace package snap_buffer as 20 | procedure start_snap; 21 | procedure end_snap; 22 | end; 23 | / 24 | 25 | create or replace package body snap_buffer as 26 | 27 | cursor c1 is 28 | select 29 | id, 30 | name, 31 | block_size, 32 | set_msize, 33 | cnum_repl, 34 | cnum_write, 35 | cnum_set, 36 | buf_got, 37 | sum_write, 38 | sum_scan, 39 | free_buffer_wait, 40 | write_complete_wait, 41 | buffer_busy_wait, 42 | free_buffer_inspected, 43 | dirty_buffers_inspected, 44 | db_block_change, 45 | db_block_gets, 46 | consistent_gets, 47 | physical_reads, 48 | physical_writes 49 | from 50 | v$buffer_pool_statistics 51 | ; 52 | 53 | 54 | type w_type is table of c1%rowtype index by binary_integer; 55 | w_list w_type; 56 | w_empty_list w_type; 57 | 58 | 59 | m_start_time date; 60 | m_start_flag char(1); 61 | m_end_time date; 62 | 63 | procedure start_snap is 64 | begin 65 | 66 | m_start_time := sysdate; 67 | m_start_flag := 'U'; 68 | w_list := w_empty_list; 69 | 70 | for r in c1 loop 71 | w_list(r.id).name := r.name; 72 | w_list(r.id).block_size := r.block_size; 73 | w_list(r.id).set_msize := r.set_msize; 74 | w_list(r.id).cnum_repl := r.cnum_repl; 75 | w_list(r.id).cnum_write := r.cnum_write; 76 | w_list(r.id).cnum_set := r.cnum_set; 77 | w_list(r.id).buf_got := r.buf_got; 78 | w_list(r.id).sum_write := r.sum_write; 79 | w_list(r.id).sum_scan := r.sum_scan; 80 | w_list(r.id).free_buffer_wait := r.free_buffer_wait; 81 | w_list(r.id).write_complete_wait := r.write_complete_wait; 82 | w_list(r.id).buffer_busy_wait := r.buffer_busy_wait; 83 | w_list(r.id).free_buffer_inspected := r.free_buffer_inspected; 84 | w_list(r.id).dirty_buffers_inspected := r.dirty_buffers_inspected; 85 | w_list(r.id).db_block_change := r.db_block_change; 86 | w_list(r.id).db_block_gets := r.db_block_gets; 87 | w_list(r.id).consistent_gets := r.consistent_gets; 88 | w_list(r.id).physical_reads := r.physical_reads; 89 | w_list(r.id).physical_writes := r.physical_writes; 90 | end loop; 91 | 92 | end start_snap; 93 | 94 | 95 | procedure end_snap is 96 | begin 97 | 98 | m_end_time := sysdate; 99 | 100 | dbms_output.put_line('-----------------------------------'); 101 | dbms_output.put_line('Buffer pool stats - ' || 102 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 103 | ); 104 | 105 | if m_start_flag = 'U' then 106 | dbms_output.put_line('Interval:- ' || 107 | trunc(86400 * (m_end_time - m_start_time)) || 108 | ' seconds' 109 | ); 110 | else 111 | dbms_output.put_line('Since Startup:- ' || 112 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 113 | ); 114 | end if; 115 | 116 | dbms_output.put_line('-----------------------------------'); 117 | 118 | dbms_output.put_line( 119 | rpad('Name',12) || 120 | lpad('Blk Size',8) || 121 | lpad('CU Gets',14) || 122 | lpad('CR Gets',14) || 123 | lpad('Blk Change',14) || 124 | lpad('Reads',14) || 125 | lpad('Writes',14) || 126 | lpad('fb waits',14) || 127 | lpad('Wc waits',14) || 128 | lpad('bb waits',14) || 129 | lpad('free insp',14) || 130 | lpad('dirty insp',14) 131 | ); 132 | 133 | dbms_output.put_line( 134 | rpad('-',12,'-') || 135 | lpad('--------',8) || 136 | lpad('----------',14) || 137 | lpad('----------',14) || 138 | lpad('----------',14) || 139 | lpad('----------',14) || 140 | lpad('----------',14) || 141 | lpad('----------',14) || 142 | lpad('----------',14) || 143 | lpad('----------',14) || 144 | lpad('----------',14) || 145 | lpad('----------',14) 146 | ); 147 | 148 | for r in c1 loop 149 | if (not w_list.exists(r.id)) then 150 | w_list(r.id).db_block_gets := 0; 151 | w_list(r.id).db_block_change := 0; 152 | w_list(r.id).consistent_gets := 0; 153 | w_list(r.id).physical_reads := 0; 154 | w_list(r.id).physical_writes := 0; 155 | w_list(r.id).free_buffer_wait := 0; 156 | w_list(r.id).write_complete_wait := 0; 157 | w_list(r.id).buffer_busy_wait := 0; 158 | w_list(r.id).free_buffer_inspected := 0; 159 | w_list(r.id).dirty_buffers_inspected := 0; 160 | end if; 161 | 162 | if ( 163 | (w_list(r.id).db_block_gets != r.db_block_gets) 164 | or (w_list(r.id).db_block_change != r.db_block_change) 165 | or (w_list(r.id).consistent_gets != r.consistent_gets) 166 | or (w_list(r.id).physical_reads != r.physical_reads) 167 | or (w_list(r.id).physical_writes != r.physical_writes) 168 | or (w_list(r.id).free_buffer_wait != r.free_buffer_wait) 169 | or (w_list(r.id).write_complete_wait != r.write_complete_wait) 170 | or (w_list(r.id).buffer_busy_wait != r.buffer_busy_wait) 171 | or (w_list(r.id).free_buffer_inspected != r.free_buffer_inspected) 172 | or (w_list(r.id).dirty_buffers_inspected != r.dirty_buffers_inspected) 173 | ) then 174 | dbms_output.put(rpad(r.name,12)); 175 | dbms_output.put(lpad(r.block_size,8)); 176 | dbms_output.put(to_char( 177 | r.db_block_gets - w_list(r.id).db_block_gets, 178 | '9,999,999,990')); 179 | dbms_output.put(to_char( 180 | r.consistent_gets - w_list(r.id).consistent_gets, 181 | '9,999,999,990')); 182 | dbms_output.put(to_char( 183 | r.db_block_change - w_list(r.id).db_block_change, 184 | '9,999,999,990')); 185 | dbms_output.put(to_char( 186 | r.physical_reads - w_list(r.id).physical_reads, 187 | '9,999,999,990')); 188 | dbms_output.put(to_char( 189 | r.physical_writes - w_list(r.id).physical_writes, 190 | '9,999,999,990')); 191 | 192 | dbms_output.put(to_char( 193 | r.free_buffer_wait - w_list(r.id).free_buffer_wait, 194 | '9,999,999,990')); 195 | dbms_output.put(to_char( 196 | r.write_complete_wait - w_list(r.id).write_complete_wait, 197 | '9,999,999,990')); 198 | dbms_output.put(to_char( 199 | r.buffer_busy_wait - w_list(r.id).buffer_busy_wait, 200 | '9,999,999,990')); 201 | dbms_output.put(to_char( 202 | r.free_buffer_inspected - w_list(r.id).free_buffer_inspected, 203 | '9,999,999,990')); 204 | dbms_output.put(to_char( 205 | r.dirty_buffers_inspected - w_list(r.id).dirty_buffers_inspected, 206 | '9,999,999,990')); 207 | 208 | dbms_output.new_line; 209 | end if; 210 | end loop; 211 | 212 | end end_snap; 213 | 214 | 215 | begin 216 | select 217 | startup_time, 'S' 218 | into 219 | m_start_time, m_start_flag 220 | from 221 | v$instance; 222 | 223 | end snap_buffer; 224 | / 225 | 226 | 227 | drop public synonym snap_buffer; 228 | create public synonym snap_buffer for snap_buffer; 229 | grant execute on snap_buffer to public; 230 | -------------------------------------------------------------------------------- /ch_03/snap_myst.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_myst.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$mystat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Depends on view v$my_stats (see c_mystats.sql) 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_my_stats.start_snap 16 | rem -- do something 17 | rem execute snap_my_stats.end_snap 18 | rem 19 | 20 | create or replace package snap_my_stats as 21 | procedure start_snap; 22 | procedure end_snap (i_limit in number default 0); 23 | end; 24 | / 25 | 26 | create or replace package body snap_my_stats as 27 | 28 | cursor c1 is 29 | select 30 | statistic#, 31 | name, 32 | value 33 | from 34 | v$my_stats 35 | where 36 | value != 0 37 | ; 38 | 39 | 40 | type w_type is table of c1%rowtype index by binary_integer; 41 | w_list w_type; 42 | empty_list w_type; 43 | 44 | m_start_time date; 45 | m_start_flag char(1); 46 | m_end_time date; 47 | 48 | procedure start_snap is 49 | begin 50 | 51 | m_start_time := sysdate; 52 | m_start_flag := 'U'; 53 | w_list := empty_list; 54 | 55 | for r in c1 loop 56 | w_list(r.statistic#).value := r.value; 57 | end loop; 58 | 59 | end start_snap; 60 | 61 | 62 | 63 | procedure end_snap (i_limit in number default 0) 64 | is 65 | begin 66 | 67 | m_end_time := sysdate; 68 | 69 | dbms_output.put_line('---------------------------------'); 70 | dbms_output.put_line('Session stats - ' || 71 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 72 | ); 73 | 74 | if m_start_flag = 'U' then 75 | dbms_output.put_line('Interval:- ' || 76 | trunc(86400 * (m_end_time - m_start_time)) || 77 | ' seconds' 78 | ); 79 | else 80 | dbms_output.put_line('Since Startup:- ' || 81 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 82 | ); 83 | end if; 84 | 85 | if (i_limit != 0) then 86 | dbms_output.put_line('Lower limit:- ' || i_limit); 87 | end if; 88 | 89 | dbms_output.put_line('---------------------------------'); 90 | 91 | dbms_output.put_line( 92 | rpad('Name',60) || 93 | lpad('Value',18) 94 | ); 95 | 96 | dbms_output.put_line( 97 | rpad('----',60) || 98 | lpad('-----',18) 99 | ); 100 | 101 | for r in c1 loop 102 | if (not w_list.exists(r.statistic#)) then 103 | w_list(r.statistic#).value := 0; 104 | end if; 105 | 106 | if ( 107 | (r.value > w_list(r.statistic#).value + i_limit) 108 | ) then 109 | dbms_output.put(rpad(r.name,60)); 110 | dbms_output.put(to_char( 111 | r.value - w_list(r.statistic#).value, 112 | '9,999,999,999,990') 113 | ); 114 | dbms_output.new_line; 115 | end if; 116 | end loop; 117 | 118 | end end_snap; 119 | 120 | begin 121 | select 122 | logon_time, 'S' 123 | into 124 | m_start_time, m_start_flag 125 | from 126 | v$session 127 | where 128 | sid = ( 129 | select /*+ no_unnest */ sid 130 | from v$mystat 131 | where rownum = 1 132 | ); 133 | 134 | end snap_my_stats; 135 | / 136 | 137 | 138 | drop public synonym snap_my_stats; 139 | create public synonym snap_my_stats for snap_my_stats; 140 | grant execute on snap_my_stats to public; 141 | -------------------------------------------------------------------------------- /ch_03/snap_rollstat.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_rollstat.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2002 5 | rem Purpose: Package to get snapshot start and delta of v$rollstat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 120 13 | rem set trimspool on 14 | rem execute snap_rollstats.start_snap 15 | rem -- do something 16 | rem execute snap_rollstats.end_snap 17 | rem 18 | 19 | create or replace package snap_rollstats as 20 | procedure start_snap; 21 | procedure end_snap; 22 | end; 23 | / 24 | 25 | create or replace package body snap_rollstats as 26 | 27 | cursor c1 is 28 | select 29 | usn, 30 | extents, 31 | rssize/1024 rssize, 32 | hwmsize/1024 hwmsize, 33 | nvl(optsize,0)/1024 optsize, 34 | writes, 35 | gets, 36 | waits, 37 | shrinks, 38 | extends, 39 | aveshrink/1024 aveshrink, 40 | aveactive/1024 aveactive 41 | from 42 | v$rollstat 43 | order by 44 | usn 45 | ; 46 | 47 | type w_type is table of c1%rowtype index by binary_integer; 48 | w_list w_type; 49 | w_empty_list w_type; 50 | 51 | m_start_time date; 52 | m_start_flag char(1); 53 | m_end_time date; 54 | 55 | procedure start_snap is 56 | begin 57 | 58 | m_start_time := sysdate; 59 | m_start_flag := 'U'; 60 | w_list := w_empty_list; 61 | 62 | for r in c1 loop 63 | w_list(r.usn).extents := r.extents; 64 | w_list(r.usn).rssize := r.rssize; 65 | w_list(r.usn).hwmsize := r.hwmsize; 66 | w_list(r.usn).writes := r.writes; 67 | w_list(r.usn).gets := r.gets; 68 | w_list(r.usn).waits := r.waits; 69 | w_list(r.usn).shrinks := r.shrinks; 70 | w_list(r.usn).extends := r.extends; 71 | w_list(r.usn).aveshrink := r.aveshrink; 72 | w_list(r.usn).aveactive := r.aveactive; 73 | end loop; 74 | 75 | end start_snap; 76 | 77 | 78 | procedure end_snap is 79 | begin 80 | 81 | m_end_time := sysdate; 82 | 83 | dbms_output.put_line('---------------------------------'); 84 | dbms_output.put_line('Rollback stats - ' || 85 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 86 | ); 87 | 88 | if m_start_flag = 'U' then 89 | dbms_output.put_line('Interval:- ' || 90 | trunc(86400 * (m_end_time - m_start_time)) || 91 | ' seconds' 92 | ); 93 | else 94 | dbms_output.put_line('Since Startup:- ' || 95 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 96 | ); 97 | end if; 98 | 99 | dbms_output.put_line('---------------------------------'); 100 | 101 | dbms_output.put_line( 102 | 'USN ' || 103 | lpad('Ex',4) || 104 | lpad('Size K',7) || 105 | lpad('HWM K',7) || 106 | lpad('Opt K',7) || 107 | lpad('Writes',12) || 108 | lpad('Gets',9) || 109 | lpad('Waits',7) || 110 | lpad('Shr',4) || 111 | lpad('Grow',5) || 112 | lpad('Shr K',6) || 113 | lpad('Act K',7) 114 | ); 115 | 116 | dbms_output.put_line( 117 | '----' || 118 | lpad('--',4) || 119 | lpad('------',7) || 120 | lpad('-----',7) || 121 | lpad('-----',7) || 122 | lpad('------',12) || 123 | lpad('----',9) || 124 | lpad('-----',7) || 125 | lpad('---',4) || 126 | lpad('----',5) || 127 | lpad('-----',6) || 128 | lpad('------',7) 129 | ); 130 | 131 | for r in c1 loop 132 | if (not w_list.exists(r.usn)) then 133 | w_list(r.usn).extents := 0; 134 | w_list(r.usn).rssize := 0; 135 | w_list(r.usn).hwmsize := 0; 136 | w_list(r.usn).writes := 0; 137 | w_list(r.usn).gets := 0; 138 | w_list(r.usn).waits := 0; 139 | w_list(r.usn).shrinks := 0; 140 | w_list(r.usn).extends := 0; 141 | w_list(r.usn).aveshrink := 0; 142 | w_list(r.usn).aveactive := 0; 143 | end if; 144 | 145 | if ( 146 | (w_list(r.usn).extents != r.extents) 147 | or (w_list(r.usn).rssize != r.rssize) 148 | or (w_list(r.usn).hwmsize != r.hwmsize) 149 | or (w_list(r.usn).writes != r.writes) 150 | or (w_list(r.usn).gets != r.gets) 151 | or (w_list(r.usn).waits != r.waits) 152 | or (w_list(r.usn).shrinks != r.shrinks) 153 | or (w_list(r.usn).extends != r.extends) 154 | or (w_list(r.usn).aveshrink != r.aveshrink) 155 | or (w_list(r.usn).aveactive != r.aveactive) 156 | ) then 157 | dbms_output.put(to_char(r.usn,'990')); 158 | dbms_output.put(to_char( 159 | r.extents - w_list(r.usn).extents, 160 | '990') 161 | ); 162 | dbms_output.put(to_char( 163 | r.rssize - w_list(r.usn).rssize, 164 | '999990') 165 | ); 166 | dbms_output.put(to_char( 167 | r.hwmsize - w_list(r.usn).hwmsize, 168 | '999990') 169 | ); 170 | dbms_output.put(to_char(r.optsize,'999990') 171 | ); 172 | dbms_output.put(to_char( 173 | r.writes - w_list(r.usn).writes, 174 | '99999999990') 175 | ); 176 | dbms_output.put(to_char( 177 | r.gets - w_list(r.usn).gets, 178 | '99999990') 179 | ); 180 | dbms_output.put(to_char( 181 | r.waits - w_list(r.usn).waits, 182 | '999990') 183 | ); 184 | dbms_output.put(to_char( 185 | r.shrinks - w_list(r.usn).shrinks, 186 | '990') 187 | ); 188 | dbms_output.put(to_char( 189 | r.extends - w_list(r.usn).extends, 190 | '9990') 191 | ); 192 | dbms_output.put(to_char( 193 | r.aveshrink - w_list(r.usn).aveshrink, 194 | '99990') 195 | ); 196 | dbms_output.put_line(to_char( 197 | r.aveactive - w_list(r.usn).aveactive, 198 | '999990') 199 | ); 200 | end if; 201 | end loop; 202 | 203 | end end_snap; 204 | 205 | 206 | begin 207 | select 208 | startup_time, 'S' 209 | into 210 | m_start_time, m_start_flag 211 | from 212 | v$instance; 213 | 214 | end snap_rollstats; 215 | / 216 | 217 | 218 | drop public synonym snap_rollstats; 219 | create public synonym snap_rollstats for snap_rollstats; 220 | grant execute on snap_rollstats to public; 221 | 222 | 223 | 224 | -------------------------------------------------------------------------------- /ch_03/snap_stat.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_stat.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$sysstat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 120 13 | rem set trimspool on 14 | rem execute snap_stats.start_snap 15 | rem -- do something 16 | rem execute snap_stats.end_snap 17 | rem 18 | 19 | create or replace package snap_stats as 20 | procedure start_snap; 21 | procedure end_snap (i_limit in number default 0); 22 | end; 23 | / 24 | 25 | create or replace package body snap_stats as 26 | 27 | cursor c1 is 28 | select 29 | statistic#, 30 | name, 31 | value 32 | from 33 | v$sysstat 34 | ; 35 | 36 | 37 | type w_type is table of c1%rowtype index by binary_integer; 38 | w_list w_type; 39 | w_empty_list w_type; 40 | 41 | m_start_time date; 42 | m_start_flag char(1); 43 | m_end_time date; 44 | 45 | procedure start_snap is 46 | begin 47 | 48 | m_start_time := sysdate; 49 | m_start_flag := 'U'; 50 | w_list := w_empty_list; 51 | 52 | for r in c1 loop 53 | w_list(r.statistic#).value := r.value; 54 | end loop; 55 | 56 | end start_snap; 57 | 58 | 59 | procedure end_snap (i_limit in number default 0) 60 | is 61 | begin 62 | 63 | m_end_time := sysdate; 64 | 65 | dbms_output.put_line('---------------------------------'); 66 | dbms_output.put_line('System stats:- ' || 67 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 68 | ); 69 | 70 | if m_start_flag = 'U' then 71 | dbms_output.put_line('Interval:- ' || 72 | trunc(86400 * (m_end_time - m_start_time)) || 73 | ' seconds' 74 | ); 75 | else 76 | dbms_output.put_line('Since Startup:- ' || 77 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 78 | ); 79 | end if; 80 | 81 | if (i_limit != 0) then 82 | dbms_output.put_line('Lower limit:- ' || i_limit); 83 | end if; 84 | 85 | dbms_output.put_line('---------------------------------'); 86 | 87 | dbms_output.put_line( 88 | rpad('Name',60) || 89 | lpad('Value',18) 90 | ); 91 | 92 | dbms_output.put_line( 93 | rpad('----',60) || 94 | lpad('-----',18) 95 | ); 96 | 97 | for r in c1 loop 98 | if (not w_list.exists(r.statistic#)) then 99 | w_list(r.statistic#).value := 0; 100 | end if; 101 | 102 | if ( 103 | (r.value > w_list(r.statistic#).value + i_limit) 104 | ) then 105 | dbms_output.put(rpad(r.name,60)); 106 | dbms_output.put(to_char( 107 | r.value - w_list(r.statistic#).value, 108 | '9,999,999,999,990')); 109 | dbms_output.new_line; 110 | end if; 111 | end loop; 112 | 113 | end end_snap; 114 | 115 | begin 116 | 117 | select 118 | startup_time, 'S' 119 | into 120 | m_start_time, m_start_flag 121 | from 122 | v$instance 123 | ; 124 | 125 | end snap_stats; 126 | / 127 | 128 | 129 | drop public synonym snap_stats; 130 | create public synonym snap_stats for snap_stats; 131 | grant execute on snap_stats to public; 132 | -------------------------------------------------------------------------------- /ch_06/c_mystats.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_mystats.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Put names to v$mystat 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 10.2.0.3 10 | rem 10.1.0.4 11 | rem 9.2.0.8 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Should be run by SYS - which means it has to be re-run 16 | rem on a full database export/import 17 | 18 | rem 19 | rem Option 1 - using v$ 20 | rem Use first_rows and ordered to avoid a sort/merge join, and 21 | rem to allow faster elimination of the 'value = 0' rows. 22 | rem 23 | 24 | create or replace view v$my_stats 25 | as 26 | select 27 | /*+ 28 | first_rows 29 | ordered 30 | */ 31 | ms.sid, 32 | sn.statistic#, 33 | sn.name, 34 | sn.class, 35 | ms.value 36 | from 37 | v$mystat ms, 38 | v$statname sn 39 | where 40 | sn.statistic# = ms.statistic# 41 | ; 42 | 43 | rem 44 | rem Option 2 - using x$ 45 | rem Avoids the filter subquery for count(*) from x$ksusd 46 | rem (See v$fixed_view_definition) 47 | rem 48 | 49 | create or replace view v$my_stats 50 | as 51 | select 52 | /*+ 53 | first_rows 54 | ordered 55 | */ 56 | ms.ksusenum sid, 57 | sn.indx statistic#, 58 | sn.ksusdnam name, 59 | sn.ksusdcls class, 60 | ms.ksusestv value 61 | from 62 | x$ksumysta ms, 63 | x$ksusd sn 64 | where 65 | ms.inst_id = sys_context('userenv','instance') 66 | and bitand(ms.ksspaflg,1)!=0 67 | and bitand(ms.ksuseflg,1)!=0 68 | and sn.inst_id = sys_context('userenv','instance') 69 | and sn.indx = ms.ksusestn 70 | ; 71 | 72 | drop public synonym v$my_stats; 73 | create public synonym v$my_stats for v$my_stats; 74 | grant select on v$my_stats to public; 75 | -------------------------------------------------------------------------------- /ch_06/setenv.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: setenv.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: June 2002 5 | rem Purpose: Set up various SQL*Plus formatting commands. 6 | rem 7 | rem Notes: 8 | rem 9 | 10 | set pause off 11 | 12 | rem 13 | rem If you want to call dbms_xplan.display_cursor() to get the 14 | rem place for the last statement you executed you will have to 15 | rem set serveroutput off 16 | rem 17 | 18 | set serveroutput on size 1000000 format wrapped 19 | 20 | rem 21 | rem I'd like to enable java output, but it seems 22 | rem to push the UGA up by about 4MB when I do it 23 | rem 24 | 25 | rem execute dbms_java.set_output(1000000) 26 | 27 | rem 28 | rem Reminder about DOC, and using the # to end DOC 29 | rem the SET command stops doc material from appearing 30 | rem 31 | 32 | execute dbms_random.seed(0) 33 | 34 | set doc off 35 | doc 36 | 37 | end doc is marked with # 38 | 39 | # 40 | 41 | set linesize 120 42 | set trimspool on 43 | set pagesize 24 44 | set arraysize 25 45 | 46 | -- set longchunksize 32768 47 | -- set long 32768 48 | 49 | set autotrace off 50 | 51 | clear breaks 52 | ttitle off 53 | btitle off 54 | 55 | column owner format a15 56 | column segment_name format a20 57 | column table_name format a20 58 | column index_name format a20 59 | column object_name format a20 60 | column subobject_name format a20 61 | column partition_name format a20 62 | column subpartition_name format a20 63 | column column_name format a20 64 | column column_expression format a40 word wrap 65 | column constraint_name format a20 66 | 67 | column referenced_name format a30 68 | 69 | column file_name format a60 70 | 71 | column low_value format a24 72 | column high_value format a24 73 | 74 | column parent_id_plus_exp format 999 75 | column id_plus_exp format 990 76 | column plan_plus_exp format a90 77 | column object_node_plus_exp format a14 78 | column other_plus_exp format a90 79 | column other_tag_plus_exp format a29 80 | 81 | column access_predicates format a80 82 | column filter_predicates format a80 83 | column projection format a80 84 | column remarks format a80 85 | column partition_start format a12 86 | column partition_stop format a12 87 | column partition_id format 999 88 | column other_tag format a32 89 | column object_alias format a24 90 | 91 | column object_node format a13 92 | column other format a150 93 | 94 | column os_username format a30 95 | column terminal format a24 96 | column userhost format a24 97 | column client_id format a24 98 | 99 | column statistic_name format a35 100 | 101 | column namespace format a20 102 | column attribute format a20 103 | 104 | column hint format a40 105 | 106 | column start_time format a25 107 | column end_time format a25 108 | 109 | column time_now noprint new_value m_timestamp 110 | 111 | set feedback off 112 | 113 | select to_char(sysdate,'hh24miss') time_now from dual; 114 | commit; 115 | 116 | set feedback on 117 | 118 | set timing off 119 | set verify off 120 | 121 | alter session set optimizer_mode = all_rows; 122 | 123 | spool log 124 | 125 | -------------------------------------------------------------------------------- /ch_06/snap_11_sysev.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_sysev.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$system_event 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Needed particularly because PX events are not forwarded to the QC 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 120 13 | rem set trimspool on 14 | rem execute snap_system_events.start_snap 15 | rem -- do something 16 | rem execute snap_system_events.end_snap 17 | rem 18 | 19 | create or replace package snap_system_events as 20 | procedure start_snap; 21 | procedure end_snap; 22 | end; 23 | . 24 | / 25 | 26 | 27 | create or replace package body snap_system_events as 28 | 29 | cursor c1(i_time_factor in number) is 30 | select 31 | d.indx indx, 32 | d.kslednam event, 33 | /* 34 | s.ksleswts total_waits, 35 | s.kslestim/i_time_factor time_waited, 36 | s.kslestmo time_outs, 37 | s.kslesmxt/i_time_factor max_time 38 | */ 39 | (s.ksleswts_un + s.ksleswts_fg + s.ksleswts_bg) total_waits, 40 | round((s.kslestim_un +s.kslestim_fg + s.kslestim_bg)/i_time_factor) time_waited, 41 | (s.kslestmo_un + s.kslestmo_fg + s.kslestmo_bg) time_outs, 42 | 0 max_time 43 | from 44 | x$kslei s, 45 | x$ksled d 46 | where s.indx = d.indx 47 | and (s.ksleswts_un > 0 or s.ksleswts_fg > 0 or s.ksleswts_bg > 0) 48 | order by 49 | d.indx 50 | ; 51 | 52 | type w_type is table of c1%rowtype index by binary_integer; 53 | w_list w_type; 54 | w_empty_list w_type; 55 | 56 | m_time_factor number(10,0); 57 | 58 | m_start_time date; 59 | m_start_flag char(1); 60 | m_end_time date; 61 | 62 | 63 | procedure start_snap is 64 | 65 | begin 66 | 67 | m_start_time := sysdate; 68 | m_start_flag := 'U'; 69 | w_list := w_empty_list; 70 | 71 | for r in c1(m_time_factor) loop 72 | w_list(r.indx).total_waits := r.total_waits; 73 | w_list(r.indx).time_waited := r.time_waited; 74 | w_list(r.indx).time_outs := r.time_outs; 75 | end loop; 76 | 77 | end start_snap; 78 | 79 | procedure end_snap is 80 | 81 | begin 82 | 83 | m_end_time := sysdate; 84 | dbms_output.put_line('---------------------------------'); 85 | dbms_output.put_line('System Waits:- ' || 86 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 87 | ); 88 | 89 | if m_start_flag = 'U' then 90 | dbms_output.put_line('Interval:- ' || 91 | trunc(86400 * (m_end_time - m_start_time)) || 92 | ' seconds' 93 | ); 94 | else 95 | dbms_output.put_line('Since Startup:- ' || 96 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 97 | ); 98 | end if; 99 | 100 | dbms_output.put_line('---------------------------------'); 101 | 102 | dbms_output.put_line( 103 | rpad('Event',43) || 104 | lpad('Waits',12) || 105 | lpad('Time_outs',12) || 106 | lpad('Csec',16) || 107 | lpad('Avg Csec',12) || 108 | lpad('Max Csec',12) 109 | ); 110 | 111 | dbms_output.put_line( 112 | rpad('-----',43) || 113 | lpad('-----',12) || 114 | lpad('---------',12) || 115 | lpad('----',16) || 116 | lpad('--------',12) || 117 | lpad('--------',12) 118 | ); 119 | 120 | for r in c1(m_time_factor) loop 121 | 122 | if (not w_list.exists(r.indx)) then 123 | w_list(r.indx).total_waits := 0; 124 | w_list(r.indx).time_waited := 0; 125 | w_list(r.indx).time_outs := 0; 126 | end if; 127 | 128 | if ( 129 | (w_list(r.indx).total_waits != r.total_waits) 130 | or (w_list(r.indx).time_waited != r.time_waited) 131 | ) then 132 | 133 | dbms_output.put(rpad(substr(r.event,1,43),43)); 134 | dbms_output.put(to_char( 135 | r.total_waits - w_list(r.indx).total_waits, 136 | '999,999,990') 137 | ); 138 | dbms_output.put(to_char( 139 | r.time_outs - w_list(r.indx).time_outs, 140 | '999,999,990')); 141 | dbms_output.put(to_char( 142 | r.time_waited - w_list(r.indx).time_waited, 143 | '999,999,999,990')); 144 | dbms_output.put(to_char( 145 | (r.time_waited - w_list(r.indx).time_waited)/ 146 | greatest( 147 | r.total_waits - w_list(r.indx).total_waits, 148 | 1 149 | ), 150 | '999,999.990')); 151 | dbms_output.put(to_char(r.max_time,'999,999,990')); 152 | dbms_output.new_line; 153 | end if; 154 | 155 | end loop; 156 | 157 | end end_snap; 158 | 159 | begin 160 | 161 | select 162 | startup_time, 'S' 163 | into 164 | m_start_time, m_start_flag 165 | from 166 | v$instance; 167 | 168 | select decode(substr(version,1,1),'8',1,'7',1,10000) 169 | into m_time_factor 170 | from v$instance 171 | ; 172 | 173 | end snap_system_events; 174 | . 175 | / 176 | 177 | 178 | drop public synonym snap_system_events; 179 | create public synonym snap_system_events for snap_system_events; 180 | grant execute on snap_system_events to public; 181 | -------------------------------------------------------------------------------- /ch_06/snap_9_latch.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_latch.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of latch stats 6 | rem 7 | rem Notes 8 | rem Version 9/10 specific - remove references to wait_time for version 8 9 | rem Has to be run by SYS to create the package 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 168 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap 16 | rem -- do something 17 | rem execute snap_latch.end_snap 18 | rem 19 | rem We only capture sleep1 to sleep3 as the rest are fake columns 20 | rem and do not (appear to) capture any data. 21 | rem 22 | rem We could consider not selecting the latch name in the main 23 | rem cursor, and use the latch number to get the latch name from 24 | rem x$kslld at print time, as this would reduce the memory demand 25 | rem of the package 26 | rem 27 | 28 | create or replace package snap_latch as 29 | procedure start_snap; 30 | procedure end_snap( 31 | i_limit in number default 0, 32 | i_all_sleeps in boolean default false 33 | ); 34 | end; 35 | / 36 | 37 | create or replace package body snap_latch as 38 | 39 | cursor c1 is 40 | select 41 | la.latch# indx, 42 | d.kslldnam name, 43 | la.gets, 44 | la.misses, 45 | la.sleeps, 46 | la.sleep1, 47 | la.sleep2, 48 | la.sleep3, 49 | la.immediate_gets, 50 | la.immediate_misses, 51 | la.spin_gets, 52 | la.waits_holding_latch, 53 | la.waiters_woken, 54 | round(la.wait_time/1000,1) wait_time 55 | from 56 | x$kslld d, 57 | ( 58 | select 59 | kslltnum latch#, 60 | sum(kslltwgt) gets, 61 | sum(kslltwff) misses, 62 | sum(kslltwsl) sleeps, 63 | sum(kslltngt) immediate_gets, 64 | sum(kslltnfa) immediate_misses, 65 | sum(kslltwkc) waiters_woken, 66 | sum(kslltwth) waits_holding_latch, 67 | sum(ksllthst0) spin_gets, 68 | sum(ksllthst1) sleep1, 69 | sum(ksllthst2) sleep2, 70 | sum(ksllthst3) sleep3, 71 | sum(kslltwtt) wait_time 72 | from 73 | x$ksllt 74 | group by kslltnum 75 | ) la 76 | where la.latch# = d.indx 77 | order by 78 | la.latch# 79 | ; 80 | 81 | 82 | type w_type is table of c1%rowtype index by binary_integer; 83 | w_list w_type; 84 | w_empty_list w_type; 85 | 86 | m_start_time date; 87 | m_start_flag char(1); 88 | m_end_time date; 89 | 90 | procedure start_snap is 91 | begin 92 | 93 | m_start_time := sysdate; 94 | m_start_flag := 'U'; 95 | w_list := w_empty_list; 96 | 97 | for r in c1 loop 98 | w_list(r.indx).gets := r.gets; 99 | w_list(r.indx).misses := r.misses; 100 | w_list(r.indx).sleeps := r.sleeps; 101 | w_list(r.indx).sleep1 := r.sleep1; 102 | w_list(r.indx).sleep2 := r.sleep2; 103 | w_list(r.indx).sleep3 := r.sleep3; 104 | w_list(r.indx).spin_gets := r.spin_gets; 105 | w_list(r.indx).immediate_gets := r.immediate_gets; 106 | w_list(r.indx).immediate_misses := r.immediate_misses; 107 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 108 | w_list(r.indx).waiters_woken := r.waiters_woken; 109 | w_list(r.indx).wait_time := r.wait_time; 110 | end loop; 111 | 112 | end start_snap; 113 | 114 | 115 | procedure end_snap( 116 | i_limit in number default 0, 117 | i_all_sleeps in boolean default false 118 | ) 119 | is 120 | begin 121 | 122 | m_end_time := sysdate; 123 | 124 | dbms_output.put_line('---------------------------------'); 125 | dbms_output.put_line('Latch waits:- ' || 126 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 127 | ); 128 | 129 | if m_start_flag = 'U' then 130 | dbms_output.put_line('Interval:- ' || 131 | trunc(86400 * (m_end_time - m_start_time)) || 132 | ' seconds' 133 | ); 134 | else 135 | dbms_output.put_line('Since Startup:- ' || 136 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 137 | ); 138 | end if; 139 | 140 | if (i_limit != 0) then 141 | dbms_output.put_line('Lower limit:- ' || i_limit); 142 | end if; 143 | 144 | dbms_output.put_line('---------------------------------'); 145 | 146 | dbms_output.put( 147 | rpad('Latch',24) || 148 | lpad('Gets',15) || 149 | lpad('Misses',12) || 150 | lpad('Sp_Get',11) || 151 | lpad('Sleeps',11) 152 | ); 153 | 154 | if (i_all_sleeps) then 155 | dbms_output.put( 156 | lpad('Sleep1',11) || 157 | lpad('Sleep2',11) || 158 | lpad('Sleep3',11) 159 | ); 160 | end if; 161 | 162 | dbms_output.put_line( 163 | lpad('Im_Gets',12) || 164 | lpad('Im_Miss',10) || 165 | lpad('Holding',8) || 166 | lpad('Woken',6) || 167 | lpad('Time ms',8) 168 | ); 169 | 170 | dbms_output.put( 171 | rpad('-----',24) || 172 | lpad('----',15) || 173 | lpad('------',12) || 174 | lpad('------',11) || 175 | lpad('------',11) 176 | ); 177 | 178 | if (i_all_sleeps) then 179 | dbms_output.put( 180 | lpad('------',11) || 181 | lpad('------',11) || 182 | lpad('------',11) 183 | ); 184 | end if; 185 | 186 | dbms_output.put_line( 187 | lpad('-------',12) || 188 | lpad('-------',10) || 189 | lpad('-------',8) || 190 | lpad('-----',6) || 191 | lpad('-------',8) 192 | ); 193 | 194 | for r in c1 loop 195 | if (not w_list.exists(r.indx)) then 196 | w_list(r.indx).gets := 0; 197 | w_list(r.indx).misses := 0; 198 | w_list(r.indx).sleeps := 0; 199 | w_list(r.indx).sleep1 := 0; 200 | w_list(r.indx).sleep2 := 0; 201 | w_list(r.indx).sleep3 := 0; 202 | w_list(r.indx).spin_gets := 0; 203 | w_list(r.indx).immediate_gets := 0; 204 | w_list(r.indx).immediate_misses := 0; 205 | w_list(r.indx).waits_holding_latch := 0; 206 | w_list(r.indx).waiters_woken := 0; 207 | w_list(r.indx).wait_time := 0; 208 | end if; 209 | 210 | if ( 211 | (r.gets > w_list(r.indx).gets + i_limit) 212 | or (r.immediate_gets > w_list(r.indx).immediate_gets + i_limit) 213 | or (r.wait_time > w_list(r.indx).wait_time + i_limit) 214 | /* 215 | or (w_list(r.indx).misses != r.misses) 216 | or (w_list(r.indx).sleeps != r.sleeps) 217 | or (w_list(r.indx).sleep1 != r.sleep1) 218 | or (w_list(r.indx).sleep2 != r.sleep2) 219 | or (w_list(r.indx).sleep3 != r.sleep3) 220 | or (w_list(r.indx).spin_gets != r.spin_gets) 221 | or (w_list(r.indx).immediate_misses != r.immediate_misses) 222 | or (w_list(r.indx).waits_holding_latch != r.waits_holding_latch) 223 | or (w_list(r.indx).waiters_woken != r.waiters_woken) 224 | */ 225 | ) then 226 | 227 | dbms_output.put(rpad(substr(r.name,1,24),24)); 228 | dbms_output.put(to_char( 229 | r.gets - w_list(r.indx).gets, 230 | '99,999,999,990') 231 | ); 232 | dbms_output.put(to_char( 233 | r.misses - w_list(r.indx).misses, 234 | '999,999,990') 235 | ); 236 | dbms_output.put(to_char( 237 | r.spin_gets - w_list(r.indx).spin_gets, 238 | '99,999,990') 239 | ); 240 | dbms_output.put(to_char( 241 | r.sleeps - w_list(r.indx).sleeps, 242 | '99,999,990') 243 | ); 244 | 245 | if (i_all_sleeps) then 246 | dbms_output.put(to_char( 247 | r.sleep1 - w_list(r.indx).sleep1, 248 | '99,999,990') 249 | ); 250 | dbms_output.put(to_char( 251 | r.sleep2 - w_list(r.indx).sleep2, 252 | '99,999,990') 253 | ); 254 | dbms_output.put(to_char( 255 | r.sleep3 - w_list(r.indx).sleep3, 256 | '99,999,990') 257 | ); 258 | end if; 259 | 260 | dbms_output.put(to_char( 261 | r.immediate_gets - w_list(r.indx).immediate_gets, 262 | '999,999,990') 263 | ); 264 | dbms_output.put(to_char( 265 | r.immediate_misses - w_list(r.indx).immediate_misses, 266 | '9,999,990') 267 | ); 268 | dbms_output.put(to_char( 269 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 270 | '999,990') 271 | ); 272 | dbms_output.put(to_char( 273 | r.waiters_woken - w_list(r.indx).waiters_woken, 274 | '9,990') 275 | ); 276 | dbms_output.put(to_char( 277 | r.wait_time - w_list(r.indx).wait_time, 278 | '9,999.0') 279 | ); 280 | dbms_output.new_line; 281 | end if; 282 | 283 | end loop; 284 | 285 | 286 | end end_snap; 287 | 288 | begin 289 | select 290 | startup_time, 'S' 291 | into 292 | m_start_time, m_start_flag 293 | from 294 | v$instance; 295 | 296 | end snap_latch; 297 | / 298 | 299 | 300 | drop public synonym snap_latch; 301 | create public synonym snap_latch for snap_latch; 302 | grant execute on snap_latch to public; 303 | -------------------------------------------------------------------------------- /ch_06/snap_events.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_events.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$session_event 6 | rem of the current session. 7 | rem 8 | rem Notes 9 | rem Has to be run by SYS to create the package 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_events.start_snap 16 | rem -- do something 17 | rem execute snap_events.end_snap 18 | rem 19 | rem Note - there is a bug in Oracle 9.2.0.1/2, which records events against 20 | rem the wrong sid in v$session_event. This code has been patched to work 21 | rem around this bug. (Fixed in 9.2.0.3) See the cursor definition below. 22 | rem 23 | 24 | create or replace package snap_events as 25 | procedure start_snap; 26 | procedure end_snap; 27 | end; 28 | . 29 | / 30 | 31 | 32 | create or replace package body snap_events as 33 | 34 | cursor c1(i_time_factor in number, i_sid in number) is 35 | select 36 | s.indx indx, 37 | d.kslednam event, 38 | s.ksleswts total_waits, 39 | s.kslestmo time_outs, 40 | s.kslestim/i_time_factor time_waited, 41 | s.kslesmxt/i_time_factor max_time 42 | from 43 | x$ksles s, 44 | x$ksled d 45 | where s.kslesenm = d.indx 46 | and s.ksleswts != 0 47 | /* 48 | use the following line for Oracle 8 and 9.2.0.3/4 and 10g 49 | */ 50 | and s.kslessid = i_sid 51 | /* 52 | Use the following line for Oracle 9.2.0.1 and 9.2.0.2 53 | and s.kslessid = i_sid - 1 54 | */ 55 | order by 56 | d.indx 57 | ; 58 | 59 | type w_type is table of c1%rowtype index by binary_integer; 60 | w_list w_type; 61 | w_empty_list w_type; 62 | 63 | g_time_factor number(10,0); 64 | g_curr_sid number(4,0); 65 | 66 | m_start_time date; 67 | m_start_flag char(1); 68 | m_end_time date; 69 | 70 | procedure start_snap is 71 | 72 | begin 73 | 74 | m_start_time := sysdate; 75 | m_start_flag := 'U'; 76 | w_list := w_empty_list; 77 | 78 | for r in c1(g_time_factor, g_curr_sid) loop 79 | w_list(r.indx).total_waits := r.total_waits; 80 | w_list(r.indx).time_waited := r.time_waited; 81 | w_list(r.indx).time_outs := r.time_outs; 82 | end loop; 83 | 84 | end start_snap; 85 | 86 | 87 | procedure end_snap is 88 | 89 | m_sid_name varchar2(255); 90 | 91 | begin 92 | m_end_time := sysdate; 93 | 94 | select username || ' - ' || osuser 95 | into m_sid_name 96 | from v$session 97 | where sid = g_curr_sid; 98 | 99 | dbms_output.put_line('---------------------------------------------------------'); 100 | 101 | dbms_output.put_line( 102 | 'SID: ' || to_char(g_curr_sid,'9999') || ':' || 103 | m_sid_name 104 | ); 105 | 106 | dbms_output.put_line('Session Events - ' || 107 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 108 | ); 109 | 110 | if m_start_flag = 'U' then 111 | dbms_output.put_line('Interval:- ' || 112 | trunc(86400 * (m_end_time - m_start_time)) || 113 | ' seconds' 114 | ); 115 | else 116 | dbms_output.put_line('Since Startup:- ' || 117 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 118 | ); 119 | end if; 120 | 121 | dbms_output.put_line('---------------------------------------------------------'); 122 | 123 | dbms_output.put_line( 124 | rpad('Event',43) || 125 | lpad('Waits',12) || 126 | lpad('Time_outs',12) || 127 | lpad('Csec',12) || 128 | lpad('Avg Csec',12) || 129 | lpad('Max Csec',12) 130 | ); 131 | 132 | dbms_output.put_line( 133 | rpad('-----',43) || 134 | lpad('-----',12) || 135 | lpad('---------',12) || 136 | lpad('----',12) || 137 | lpad('--------',12) || 138 | lpad('--------',12) 139 | ); 140 | 141 | 142 | for r in c1(g_time_factor, g_curr_sid) loop 143 | 144 | if (not w_list.exists(r.indx)) then 145 | w_list(r.indx).total_waits := 0; 146 | w_list(r.indx).time_waited := 0; 147 | w_list(r.indx).time_outs := 0; 148 | end if; 149 | 150 | if ( 151 | (w_list(r.indx).total_waits != r.total_waits) 152 | or (w_list(r.indx).time_waited != r.time_waited) 153 | ) then 154 | 155 | 156 | dbms_output.put(rpad( substr(r.event,1,43),43)); 157 | dbms_output.put(to_char( 158 | r.total_waits - w_list(r.indx).total_waits, 159 | '999,999,990') 160 | ); 161 | dbms_output.put(to_char( 162 | r.time_outs - w_list(r.indx).time_outs, 163 | '999,999,990') 164 | ); 165 | dbms_output.put(to_char( 166 | r.time_waited - w_list(r.indx).time_waited, 167 | '999,999,990')); 168 | dbms_output.put(to_char( 169 | (r.time_waited - w_list(r.indx).time_waited)/ 170 | greatest( 171 | r.total_waits - w_list(r.indx).total_waits, 172 | 1 173 | ), 174 | '999,999.990')); 175 | dbms_output.put_line(to_char( 176 | r.max_time,'999,999,990') 177 | ); 178 | end if; 179 | 180 | end loop; 181 | 182 | end end_snap; 183 | 184 | begin 185 | select decode(substr(version,1,1),'8',1,'7',1,10000) 186 | into g_time_factor 187 | from v$instance; 188 | 189 | select sid 190 | into g_curr_sid 191 | from v$mystat 192 | where rownum = 1; 193 | 194 | select 195 | logon_time, 'S' 196 | into 197 | m_start_time, m_start_flag 198 | from 199 | v$session 200 | where 201 | sid = g_curr_sid; 202 | 203 | end snap_events; 204 | . 205 | / 206 | 207 | 208 | drop public synonym snap_events; 209 | create public synonym snap_events for snap_events; 210 | grant execute on snap_events to public; 211 | 212 | -------------------------------------------------------------------------------- /ch_06/snap_my_redo.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_my_redo.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of redo from v$mystat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Reports stats containing the word 'redo' 10 | rem and stats starting with the word 'messages' 11 | rem (the latter is for messages sent to the log writer) 12 | rem 13 | rem Usage: 14 | rem set serveroutput on size 1000000 format wrapped 15 | rem set linesize 120 16 | rem set trimspool on 17 | rem execute snap_my_redo.start_snap 18 | rem -- do something 19 | rem execute snap_my_redo.end_snap 20 | rem 21 | 22 | create or replace package snap_my_redo as 23 | procedure start_snap; 24 | procedure end_snap; 25 | end; 26 | / 27 | 28 | create or replace package body snap_my_redo as 29 | 30 | cursor c1 is 31 | select 32 | statistic#, 33 | name, 34 | value 35 | from 36 | v$my_stats 37 | where 38 | name like '%redo%' 39 | or name like 'messages%' 40 | or name like '%kcm%' 41 | ; 42 | 43 | 44 | type w_type is table of c1%rowtype index by binary_integer; 45 | w_list w_type; 46 | empty_list w_type; 47 | 48 | m_start_time date; 49 | m_start_flag char(1); 50 | m_end_time date; 51 | 52 | 53 | procedure start_snap is 54 | begin 55 | 56 | m_start_time := sysdate; 57 | m_start_flag := 'U'; 58 | w_list := empty_list; 59 | 60 | for r in c1 loop 61 | w_list(r.statistic#).value := r.value; 62 | end loop; 63 | 64 | end start_snap; 65 | 66 | 67 | procedure end_snap is 68 | begin 69 | 70 | m_end_time := sysdate; 71 | 72 | dbms_output.put_line('-------------------------------------'); 73 | dbms_output.put_line('MY REDO stats - ' || 74 | to_char(sysdate,'dd-Mon hh24:mi:ss') 75 | ); 76 | if m_start_flag = 'U' then 77 | dbms_output.put_line('Interval:- ' || 78 | trunc(86400 * (m_end_time - m_start_time)) || 79 | ' seconds' 80 | ); 81 | else 82 | dbms_output.put_line('Since Startup:- ' || 83 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 84 | ); 85 | end if; 86 | 87 | dbms_output.put_line('-------------------------------------'); 88 | 89 | dbms_output.put_line( 90 | rpad('Name',60) || 91 | lpad('Value',18) 92 | ); 93 | 94 | dbms_output.put_line( 95 | rpad('----',60) || 96 | lpad('-----',18) 97 | ); 98 | 99 | for r in c1 loop 100 | if (not w_list.exists(r.statistic#)) then 101 | w_list(r.statistic#).value := 0; 102 | end if; 103 | 104 | if ( 105 | (w_list(r.statistic#).value != r.value) 106 | ) then 107 | dbms_output.put(rpad(r.name,60)); 108 | dbms_output.put_line(to_char( 109 | r.value - w_list(r.statistic#).value, 110 | '9,999,999,999,990')); 111 | end if; 112 | end loop; 113 | 114 | end end_snap; 115 | 116 | begin 117 | select 118 | logon_time, 'S' 119 | into 120 | m_start_time, m_start_flag 121 | from 122 | v$session 123 | where 124 | sid = ( 125 | select /*+ no_unnest */ sid 126 | from v$mystat 127 | where rownum = 1 128 | ); 129 | 130 | end snap_my_redo; 131 | / 132 | 133 | 134 | drop public synonym snap_my_redo; 135 | create public synonym snap_my_redo for snap_my_redo; 136 | grant execute on snap_my_redo to public; 137 | -------------------------------------------------------------------------------- /ch_06/snap_myst.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_myst.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$mystat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Depends on view v$my_stats (see c_mystats.sql) 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_my_stats.start_snap 16 | rem -- do something 17 | rem execute snap_my_stats.end_snap 18 | rem 19 | 20 | create or replace package snap_my_stats as 21 | procedure start_snap; 22 | procedure end_snap (i_limit in number default 0); 23 | end; 24 | / 25 | 26 | create or replace package body snap_my_stats as 27 | 28 | cursor c1 is 29 | select 30 | statistic#, 31 | name, 32 | value 33 | from 34 | v$my_stats 35 | where 36 | value != 0 37 | ; 38 | 39 | 40 | type w_type is table of c1%rowtype index by binary_integer; 41 | w_list w_type; 42 | empty_list w_type; 43 | 44 | m_start_time date; 45 | m_start_flag char(1); 46 | m_end_time date; 47 | 48 | procedure start_snap is 49 | begin 50 | 51 | m_start_time := sysdate; 52 | m_start_flag := 'U'; 53 | w_list := empty_list; 54 | 55 | for r in c1 loop 56 | w_list(r.statistic#).value := r.value; 57 | end loop; 58 | 59 | end start_snap; 60 | 61 | 62 | 63 | procedure end_snap (i_limit in number default 0) 64 | is 65 | begin 66 | 67 | m_end_time := sysdate; 68 | 69 | dbms_output.put_line('---------------------------------'); 70 | dbms_output.put_line('Session stats - ' || 71 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 72 | ); 73 | 74 | if m_start_flag = 'U' then 75 | dbms_output.put_line('Interval:- ' || 76 | trunc(86400 * (m_end_time - m_start_time)) || 77 | ' seconds' 78 | ); 79 | else 80 | dbms_output.put_line('Since Startup:- ' || 81 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 82 | ); 83 | end if; 84 | 85 | if (i_limit != 0) then 86 | dbms_output.put_line('Lower limit:- ' || i_limit); 87 | end if; 88 | 89 | dbms_output.put_line('---------------------------------'); 90 | 91 | dbms_output.put_line( 92 | rpad('Name',60) || 93 | lpad('Value',18) 94 | ); 95 | 96 | dbms_output.put_line( 97 | rpad('----',60) || 98 | lpad('-----',18) 99 | ); 100 | 101 | for r in c1 loop 102 | if (not w_list.exists(r.statistic#)) then 103 | w_list(r.statistic#).value := 0; 104 | end if; 105 | 106 | if ( 107 | (r.value > w_list(r.statistic#).value + i_limit) 108 | ) then 109 | dbms_output.put(rpad(r.name,60)); 110 | dbms_output.put(to_char( 111 | r.value - w_list(r.statistic#).value, 112 | '9,999,999,999,990') 113 | ); 114 | dbms_output.new_line; 115 | end if; 116 | end loop; 117 | 118 | end end_snap; 119 | 120 | begin 121 | select 122 | logon_time, 'S' 123 | into 124 | m_start_time, m_start_flag 125 | from 126 | v$session 127 | where 128 | sid = ( 129 | select /*+ no_unnest */ sid 130 | from v$mystat 131 | where rownum = 1 132 | ); 133 | 134 | end snap_my_stats; 135 | / 136 | 137 | 138 | drop public synonym snap_my_stats; 139 | create public synonym snap_my_stats for snap_my_stats; 140 | grant execute on snap_my_stats to public; 141 | -------------------------------------------------------------------------------- /ch_06/snap_redo.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_redo.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of redo from v$sysstat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Reports stats containing the word 'redo' 10 | rem and stats starting with the word 'messages' 11 | rem (the latter is for messages sent to the log writer) 12 | rem 13 | rem Usage: 14 | rem set serveroutput on size 1000000 format wrapped 15 | rem set linesize 120 16 | rem set trimspool on 17 | rem execute snap_redo.start_snap 18 | rem -- do something 19 | rem execute snap_redo.end_snap 20 | rem 21 | 22 | create or replace package snap_redo as 23 | procedure start_snap; 24 | procedure end_snap; 25 | end; 26 | / 27 | 28 | create or replace package body snap_redo as 29 | 30 | cursor c1 is 31 | select 32 | statistic#, 33 | name, 34 | value 35 | from 36 | v$sysstat 37 | where 38 | name like '%redo%' 39 | or name like 'messages%' 40 | or name like '%kcm%' 41 | ; 42 | 43 | 44 | type w_type is table of c1%rowtype index by binary_integer; 45 | w_list w_type; 46 | empty_list w_type; 47 | 48 | m_start_time date; 49 | m_start_flag char(1); 50 | m_end_time date; 51 | 52 | 53 | procedure start_snap is 54 | begin 55 | 56 | m_start_time := sysdate; 57 | m_start_flag := 'U'; 58 | w_list := empty_list; 59 | 60 | for r in c1 loop 61 | w_list(r.statistic#).value := r.value; 62 | end loop; 63 | 64 | end start_snap; 65 | 66 | 67 | procedure end_snap is 68 | begin 69 | 70 | m_end_time := sysdate; 71 | 72 | dbms_output.put_line('-------------------------------------'); 73 | dbms_output.put_line('System REDO stats - ' || 74 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 75 | ); 76 | if m_start_flag = 'U' then 77 | dbms_output.put_line('Interval:- ' || 78 | trunc(86400 * (m_end_time - m_start_time)) || 79 | ' seconds' 80 | ); 81 | else 82 | dbms_output.put_line('Since Startup:- ' || 83 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 84 | ); 85 | end if; 86 | 87 | dbms_output.put_line('-------------------------------------'); 88 | 89 | dbms_output.put_line( 90 | rpad('Name',60) || 91 | lpad('Value',18) 92 | ); 93 | 94 | dbms_output.put_line( 95 | rpad('----',60) || 96 | lpad('-----',18) 97 | ); 98 | 99 | for r in c1 loop 100 | if (not w_list.exists(r.statistic#)) then 101 | w_list(r.statistic#).value := 0; 102 | end if; 103 | 104 | if ( 105 | (w_list(r.statistic#).value != r.value) 106 | ) then 107 | dbms_output.put(rpad(r.name,60)); 108 | dbms_output.put_line(to_char( 109 | r.value - w_list(r.statistic#).value, 110 | '9,999,999,999,990')); 111 | end if; 112 | end loop; 113 | 114 | end end_snap; 115 | 116 | begin 117 | select 118 | logon_time, 'S' 119 | into 120 | m_start_time, m_start_flag 121 | from 122 | v$session 123 | where 124 | sid = ( 125 | select /*+ no_unnest */ sid 126 | from v$mystat 127 | where rownum = 1 128 | ); 129 | 130 | end snap_redo; 131 | / 132 | 133 | 134 | drop public synonym snap_redo; 135 | create public synonym snap_redo for snap_redo; 136 | grant execute on snap_redo to public; 137 | -------------------------------------------------------------------------------- /ch_06/snap_sysev.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_sysev.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$system_event 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Needed particularly because PX events are not forwarded to the QC 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 120 13 | rem set trimspool on 14 | rem execute snap_system_events.start_snap 15 | rem -- do something 16 | rem execute snap_system_events.end_snap 17 | rem 18 | 19 | create or replace package snap_system_events as 20 | procedure start_snap; 21 | procedure end_snap; 22 | end; 23 | . 24 | / 25 | 26 | 27 | create or replace package body snap_system_events as 28 | 29 | cursor c1(i_time_factor in number) is 30 | select 31 | d.indx indx, 32 | d.kslednam event, 33 | s.ksleswts total_waits, 34 | s.kslestim/i_time_factor time_waited, 35 | s.kslestmo time_outs, 36 | s.kslesmxt/i_time_factor max_time 37 | /* 38 | (s.ksleswts_un + s.ksleswts_fg + s.ksleswts_bg) total_waits, 39 | round((s.kslestim_un +s.kslestim_fg + s.kslestim_bg)/i_time_factor) time_waited, 40 | (s.kslestmo_un + s.kslestmo_fg + s.kslestmo_bg) time_outs, 41 | 0 max_time 42 | */ 43 | from 44 | x$kslei s, 45 | x$ksled d 46 | where s.indx = d.indx 47 | -- and (s.ksleswts_un > 0 or s.ksleswts_fg > 0 or s.ksleswts_bg > 0) 48 | and s.ksleswts > 0 49 | order by 50 | d.indx 51 | ; 52 | 53 | type w_type is table of c1%rowtype index by binary_integer; 54 | w_list w_type; 55 | w_empty_list w_type; 56 | 57 | m_time_factor number(10,0); 58 | 59 | m_start_time date; 60 | m_start_flag char(1); 61 | m_end_time date; 62 | 63 | 64 | procedure start_snap is 65 | 66 | begin 67 | 68 | m_start_time := sysdate; 69 | m_start_flag := 'U'; 70 | w_list := w_empty_list; 71 | 72 | for r in c1(m_time_factor) loop 73 | w_list(r.indx).total_waits := r.total_waits; 74 | w_list(r.indx).time_waited := r.time_waited; 75 | w_list(r.indx).time_outs := r.time_outs; 76 | end loop; 77 | 78 | end start_snap; 79 | 80 | procedure end_snap is 81 | 82 | begin 83 | 84 | m_end_time := sysdate; 85 | dbms_output.put_line('---------------------------------'); 86 | dbms_output.put_line('System Waits:- ' || 87 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 88 | ); 89 | 90 | if m_start_flag = 'U' then 91 | dbms_output.put_line('Interval:- ' || 92 | trunc(86400 * (m_end_time - m_start_time)) || 93 | ' seconds' 94 | ); 95 | else 96 | dbms_output.put_line('Since Startup:- ' || 97 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 98 | ); 99 | end if; 100 | 101 | dbms_output.put_line('---------------------------------'); 102 | 103 | dbms_output.put_line( 104 | rpad('Event',43) || 105 | lpad('Waits',12) || 106 | lpad('Time_outs',12) || 107 | lpad('Csec',16) || 108 | lpad('Avg Csec',12) || 109 | lpad('Max Csec',12) 110 | ); 111 | 112 | dbms_output.put_line( 113 | rpad('-----',43) || 114 | lpad('-----',12) || 115 | lpad('---------',12) || 116 | lpad('----',16) || 117 | lpad('--------',12) || 118 | lpad('--------',12) 119 | ); 120 | 121 | for r in c1(m_time_factor) loop 122 | 123 | if (not w_list.exists(r.indx)) then 124 | w_list(r.indx).total_waits := 0; 125 | w_list(r.indx).time_waited := 0; 126 | w_list(r.indx).time_outs := 0; 127 | end if; 128 | 129 | if ( 130 | (w_list(r.indx).total_waits != r.total_waits) 131 | or (w_list(r.indx).time_waited != r.time_waited) 132 | ) then 133 | 134 | dbms_output.put(rpad(substr(r.event,1,43),43)); 135 | dbms_output.put(to_char( 136 | r.total_waits - w_list(r.indx).total_waits, 137 | '999,999,990') 138 | ); 139 | dbms_output.put(to_char( 140 | r.time_outs - w_list(r.indx).time_outs, 141 | '999,999,990')); 142 | dbms_output.put(to_char( 143 | r.time_waited - w_list(r.indx).time_waited, 144 | '999,999,999,990')); 145 | dbms_output.put(to_char( 146 | (r.time_waited - w_list(r.indx).time_waited)/ 147 | greatest( 148 | r.total_waits - w_list(r.indx).total_waits, 149 | 1 150 | ), 151 | '999,999.990')); 152 | dbms_output.put(to_char(r.max_time,'999,999,990')); 153 | dbms_output.new_line; 154 | end if; 155 | 156 | end loop; 157 | 158 | end end_snap; 159 | 160 | begin 161 | 162 | select 163 | startup_time, 'S' 164 | into 165 | m_start_time, m_start_flag 166 | from 167 | v$instance; 168 | 169 | select decode(substr(version,1,1),'8',1,'7',1,10000) 170 | into m_time_factor 171 | from v$instance 172 | ; 173 | 174 | end snap_system_events; 175 | . 176 | / 177 | 178 | 179 | drop public synonym snap_system_events; 180 | create public synonym snap_system_events for snap_system_events; 181 | grant execute on snap_system_events to public; 182 | -------------------------------------------------------------------------------- /ch_07/c_mystats.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: c_mystats.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Put names to v$mystat 6 | rem 7 | rem Last tested 8 | rem 11.2.0.2 9 | rem 10.2.0.3 10 | rem 10.1.0.4 11 | rem 9.2.0.8 12 | rem 8.1.7.4 13 | rem 14 | rem Notes: 15 | rem Should be run by SYS - which means it has to be re-run 16 | rem on a full database export/import 17 | 18 | rem 19 | rem Option 1 - using v$ 20 | rem Use first_rows and ordered to avoid a sort/merge join, and 21 | rem to allow faster elimination of the 'value = 0' rows. 22 | rem 23 | 24 | create or replace view v$my_stats 25 | as 26 | select 27 | /*+ 28 | first_rows 29 | ordered 30 | */ 31 | ms.sid, 32 | sn.statistic#, 33 | sn.name, 34 | sn.class, 35 | ms.value 36 | from 37 | v$mystat ms, 38 | v$statname sn 39 | where 40 | sn.statistic# = ms.statistic# 41 | ; 42 | 43 | rem 44 | rem Option 2 - using x$ 45 | rem Avoids the filter subquery for count(*) from x$ksusd 46 | rem (See v$fixed_view_definition) 47 | rem 48 | 49 | create or replace view v$my_stats 50 | as 51 | select 52 | /*+ 53 | first_rows 54 | ordered 55 | */ 56 | ms.ksusenum sid, 57 | sn.indx statistic#, 58 | sn.ksusdnam name, 59 | sn.ksusdcls class, 60 | ms.ksusestv value 61 | from 62 | x$ksumysta ms, 63 | x$ksusd sn 64 | where 65 | ms.inst_id = sys_context('userenv','instance') 66 | and bitand(ms.ksspaflg,1)!=0 67 | and bitand(ms.ksuseflg,1)!=0 68 | and sn.inst_id = sys_context('userenv','instance') 69 | and sn.indx = ms.ksusestn 70 | ; 71 | 72 | drop public synonym v$my_stats; 73 | create public synonym v$my_stats for v$my_stats; 74 | grant select on v$my_stats to public; 75 | -------------------------------------------------------------------------------- /ch_07/core_dc_activity_01.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem July 2011 3 | rem core_dc_activity_01.sql 4 | rem 5 | rem Row cache activity for literal SQL 6 | rem Execute the start procedures twice to eliminate their 7 | rem impact on row cache activity 8 | rem 9 | rem Depends on 10 | rem snap_rowcache.sql 11 | rem snap_9_latch.sql (snap_11_latch.sql) 12 | rem setenv.sql 13 | rem 14 | 15 | start setenv 16 | 17 | drop table t1; 18 | purge recyclebin; 19 | 20 | create table t1 pctfree 99 pctused 1 21 | as 22 | select 23 | rownum id, 24 | rownum n1, 25 | lpad(rownum,10,'0') v1, 26 | rpad('x',100) padding 27 | from 28 | all_objects 29 | where 30 | rownum <= 10000 31 | ; 32 | 33 | 34 | create unique index t1_pk on t1(id) pctfree 99; 35 | alter table t1 add constraint t1_pk primary key(id); 36 | 37 | execute dbms_stats.gather_table_stats(user,'t1') 38 | 39 | spool core_dc_activity_01.lst 40 | 41 | execute snap_rowcache.start_snap 42 | execute snap_latch_child.start_snap('row cache objects') 43 | 44 | prompt ==================================== 45 | prompt select one column with one predicate 46 | prompt ==================================== 47 | 48 | execute snap_rowcache.start_snap 49 | execute snap_latch_child.start_snap('row cache objects') 50 | 51 | declare 52 | m_n number; 53 | m_v varchar2(10); 54 | begin 55 | for i in 1..1000 loop 56 | execute immediate 57 | 'select n1 from t1 where id = ' || i 58 | into m_n; 59 | end loop; 60 | end; 61 | / 62 | 63 | execute snap_latch_child.end_snap('row cache objects') 64 | execute snap_rowcache.end_snap 65 | 66 | prompt ===================================== 67 | prompt select two columns with one predicate 68 | prompt ===================================== 69 | 70 | execute snap_rowcache.start_snap 71 | execute snap_latch_child.start_snap('row cache objects') 72 | 73 | 74 | declare 75 | m_n number; 76 | m_v varchar2(10); 77 | begin 78 | for i in 1..1000 loop 79 | execute immediate 80 | 'select n1, v1 from t1 where id = ' || i 81 | into m_n, m_v; 82 | end loop; 83 | end; 84 | / 85 | 86 | execute snap_latch_child.end_snap('row cache objects') 87 | execute snap_rowcache.end_snap 88 | 89 | prompt ===================================== 90 | prompt select one column with two predicates 91 | prompt ===================================== 92 | 93 | execute snap_rowcache.start_snap 94 | execute snap_latch_child.start_snap('row cache objects') 95 | 96 | 97 | declare 98 | m_n number; 99 | m_v varchar2(10); 100 | begin 101 | for i in 1..1000 loop 102 | execute immediate 103 | 'select n1 from t1 where padding = rpad(''x'',100) and id = ' || i 104 | into m_n; 105 | end loop; 106 | end; 107 | / 108 | 109 | execute snap_latch_child.end_snap('row cache objects') 110 | execute snap_rowcache.end_snap 111 | 112 | 113 | prompt ====================================== 114 | prompt select two columns with two predicates 115 | prompt ====================================== 116 | 117 | execute snap_rowcache.start_snap 118 | execute snap_latch_child.start_snap('row cache objects') 119 | 120 | 121 | declare 122 | m_n number; 123 | m_v varchar2(10); 124 | begin 125 | for i in 1..1000 loop 126 | execute immediate 127 | 'select n1, v1 from t1 where padding = rpad(''x'',100) and id = ' || i 128 | into m_n, m_v; 129 | end loop; 130 | end; 131 | / 132 | 133 | execute snap_latch_child.end_snap('row cache objects') 134 | execute snap_rowcache.end_snap 135 | 136 | 137 | spool off 138 | 139 | set doc off 140 | doc 141 | 142 | 143 | Sample output from 10.2.0.3 144 | Note the line-up between the dc_entry and the latch get - and the 3x effect. 145 | 146 | --------------------------------------------------------- 147 | row cache objects latch waits - 31-Aug 08:56:17 148 | Interval:- 0 seconds 149 | --------------------------------------------------------- 150 | Address Gets Misses Spins Sleeps Im_Gets Im_Miss Holding Woken Time m/s 151 | ------- ---- ------ ------ ----- ------- ------- ------- ----- -------- 152 | 1FE4846C 6,000 0 0 0 0 0 0 0 .000 153 | 1FEC84D4 3 0 0 0 0 0 0 0 .000 154 | 1FEC910C 3,021 0 0 0 0 0 0 0 .000 155 | 1FF495DC 3,000 0 0 0 0 0 0 0 .000 156 | 1FFC9644 18 0 0 0 0 0 0 0 .000 157 | 1FFCAF14 9,018 0 0 0 0 0 0 0 .000 158 | 1F8B4E48 6,000 0 0 0 0 0 0 0 .000 159 | Latches reported: 7 160 | 161 | PL/SQL procedure successfully completed. 162 | 163 | --------------------------------- 164 | Dictionary Cache - 31-Aug 08:56:17 165 | Interval:- 0 seconds 166 | --------------------------------- 167 | Parameter Usage Fixed Gets Misses Scans Misses Comp Mods Flushes 168 | --------- ----- ----- ---- ------ ----- -------------- ---- ------- 169 | dc_segments 0 0 2,000 0 0 0 0 0 0 170 | dc_tablespaces 0 0 2 0 0 0 0 0 0 171 | dc_users 0 0 1,014 0 0 0 0 0 0 172 | dc_objects 0 0 1,001 0 0 0 0 0 0 173 | dc_global_oids 0 0 12 0 0 0 0 0 0 174 | dc_object_ids 0 0 3,012 0 0 0 0 0 0 175 | dc_histogram_defs 0 0 2,000 0 0 0 0 0 0 176 | dc_object_grants 0 0 5 0 0 0 0 0 0 177 | 178 | PL/SQL procedure successfully completed. 179 | 180 | 181 | 11g results: 182 | --------------------------------------------------------- 183 | row cache objects latch waits - 31-Aug 09:05:24 184 | Interval:- 0 seconds 185 | --------------------------------------------------------- 186 | Address Gets Misses Spins Sleeps Im_Gets Im_Miss Holding Woken Time m/s 187 | ------- ---- ------ ------ ----- ------- ------- ------- ----- -------- 188 | 2D9F08FC 12,000 0 0 0 0 0 0 0 .000 189 | 2DA71804 9,006 0 0 0 0 0 0 0 .000 190 | 2DAF1904 12,026 0 0 0 0 0 0 0 .000 191 | 2DB71A00 18 0 0 0 0 0 0 0 .000 192 | 2DB738F8 6,000 0 0 0 25 0 0 0 .000 193 | Latches reported: 5 194 | 195 | PL/SQL procedure successfully completed. 196 | 197 | --------------------------------- 198 | Dictionary Cache - 31-Aug 09:05:24 199 | Interval:- 0 seconds 200 | --------------------------------- 201 | Parameter Usage Fixed Gets Misses Scans Misses Comp Mods Flushes 202 | --------- ----- ----- ---- ------ ----- -------------- ---- ------- 203 | dc_segments 0 0 4,000 0 0 0 0 0 0 204 | dc_users 0 0 3,004 0 0 0 0 0 0 205 | dc_objects 0 0 4,014 0 0 0 0 0 0 206 | dc_global_oids 0 0 12 0 0 0 0 0 0 207 | dc_histogram_defs -57 0 2,000 0 0 0 0 0 0 208 | dc_object_grants 0 0 10 0 0 0 0 0 0 209 | dc_histogram_data -1 0 0 0 0 0 0 0 0 210 | 211 | PL/SQL procedure successfully completed. 212 | 213 | SQL> 214 | 215 | 216 | 217 | 218 | 219 | 220 | 221 | 222 | 223 | 224 | # 225 | -------------------------------------------------------------------------------- /ch_07/core_dc_activity_02.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem July 2011 3 | rem core_dc_activity_02.sql 4 | rem 5 | rem Row cache activity with use of bind variables 6 | rem Execute the start procedures twice to eliminate their 7 | rem impact on row cache activity 8 | rem 9 | rem Depends on 10 | rem snap_rowcache.sql 11 | rem snap_9_latch.sql (snap_11_latch.sql) 12 | rem setenv.sql 13 | rem c_mystats.sql 14 | rem snap_myst.sql 15 | rem snap_9_latch_child.sql 16 | rem 17 | 18 | start setenv 19 | 20 | drop table t1; 21 | purge recyclebin; 22 | 23 | create table t1 pctfree 99 pctused 1 24 | as 25 | select 26 | rownum id, 27 | rownum n1, 28 | rpad('x',100) padding 29 | from 30 | all_objects 31 | where 32 | rownum <= 10000 33 | ; 34 | 35 | 36 | create unique index t1_pk on t1(id) pctfree 99; 37 | alter table t1 add constraint t1_pk primary key(id); 38 | 39 | execute dbms_stats.gather_table_stats(user,'t1') 40 | 41 | spool core_dc_activity_02.lst 42 | 43 | execute snap_my_stats.start_snap 44 | execute snap_rowcache.start_snap 45 | execute snap_latch_child.start_snap('row cache objects') 46 | 47 | execute snap_my_stats.start_snap 48 | execute snap_rowcache.start_snap 49 | execute snap_latch_child.start_snap('row cache objects') 50 | 51 | declare 52 | m_n number; 53 | begin 54 | for i in 1..1000 loop 55 | execute immediate 56 | 'select n1 from t1 where id = :n' 57 | into m_n using i; 58 | end loop; 59 | end; 60 | / 61 | 62 | execute snap_latch_child.end_snap('row cache objects') 63 | execute snap_rowcache.end_snap 64 | execute snap_my_stats.end_snap 65 | 66 | spool off 67 | 68 | set doc off 69 | doc 70 | 71 | 72 | Sample output from 10.2.0.3 73 | 74 | --------------------------------------------------------- 75 | row cache objects latch waits - 31-Aug 09:00:45 76 | Interval:- 0 seconds 77 | --------------------------------------------------------- 78 | Address Gets Misses Spins Sleeps Im_Gets Im_Miss Holding Woken Time m/s 79 | ------- ---- ------ ------ ----- ------- ------- ------- ----- -------- 80 | 1FE4846C 6 0 0 0 0 0 0 0 .000 81 | 1FEC84D4 3 0 0 0 0 0 0 0 .000 82 | 1FEC910C 24 0 0 0 0 0 0 0 .000 83 | 1FF495DC 3 0 0 0 0 0 0 0 .000 84 | 1FFC9644 18 0 0 0 0 0 0 0 .000 85 | 1FFCAF14 27 0 0 0 0 0 0 0 .000 86 | 1F8B4E48 6 0 0 0 0 0 0 0 .000 87 | Latches reported: 7 88 | 89 | PL/SQL procedure successfully completed. 90 | 91 | --------------------------------- 92 | Dictionary Cache - 31-Aug 09:00:45 93 | Interval:- 0 seconds 94 | --------------------------------- 95 | Parameter Usage Fixed Gets Misses Scans Misses Comp Mods Flushes 96 | --------- ----- ----- ---- ------ ----- -------------- ---- ------- 97 | dc_segments 0 0 2 0 0 0 0 0 0 98 | dc_tablespaces 0 0 2 0 0 0 0 0 0 99 | dc_users 0 0 15 0 0 0 0 0 0 100 | dc_objects 0 0 1 0 0 0 0 0 0 101 | dc_global_oids 0 0 12 0 0 0 0 0 0 102 | dc_object_ids 0 0 15 0 0 0 0 0 0 103 | dc_histogram_defs 0 0 2 0 0 0 0 0 0 104 | 105 | PL/SQL procedure successfully completed. 106 | 107 | 108 | 11g results 109 | --------------------------------------------------------- 110 | row cache objects latch waits - 31-Aug 09:09:24 111 | Interval:- 0 seconds 112 | --------------------------------------------------------- 113 | Address Gets Misses Spins Sleeps Im_Gets Im_Miss Holding Woken Time m/s 114 | ------- ---- ------ ------ ----- ------- ------- ------- ----- -------- 115 | 2D9F08FC 12 0 0 0 0 0 0 0 .000 116 | 2DA71804 15 0 0 0 0 0 0 0 .000 117 | 2DAF1904 38 0 0 0 0 0 0 0 .000 118 | 2DB71A00 18 0 0 0 0 0 0 0 .000 119 | 2DB738F8 6 0 0 0 0 0 0 0 .000 120 | Latches reported: 5 121 | 122 | PL/SQL procedure successfully completed. 123 | 124 | --------------------------------- 125 | Dictionary Cache - 31-Aug 09:09:24 126 | Interval:- 0 seconds 127 | --------------------------------- 128 | Parameter Usage Fixed Gets Misses Scans Misses Comp Mods Flushes 129 | --------- ----- ----- ---- ------ ----- -------------- ---- ------- 130 | dc_segments 0 0 4 0 0 0 0 0 0 131 | dc_users 0 0 5 0 0 0 0 0 0 132 | dc_objects 0 0 18 0 0 0 0 0 0 133 | dc_global_oids 0 0 12 0 0 0 0 0 0 134 | dc_histogram_defs 0 0 2 0 0 0 0 0 0 135 | dc_object_grants 0 0 10 0 0 0 0 0 0 136 | 137 | PL/SQL procedure successfully completed. 138 | # 139 | -------------------------------------------------------------------------------- /ch_07/core_dc_activity_03.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem July 2011 3 | rem core_dc_activity_03.sql 4 | rem 5 | rem Session stats - comparing parse counts between 6 | rem literal string approach and bind variable approach 7 | rem Execute the start procedures twice to eliminate their 8 | rem impact on row cache activity 9 | rem 10 | rem Depends on 11 | rem setenv.sql 12 | rem c_mystats.sql 13 | rem snap_myst.sql 14 | rem 15 | 16 | start setenv 17 | 18 | drop table t1; 19 | purge recyclebin; 20 | 21 | create table t1 pctfree 99 pctused 1 22 | as 23 | select 24 | rownum id, 25 | rownum n1, 26 | rpad('x',100) padding 27 | from 28 | all_objects 29 | where 30 | rownum <= 10000 31 | ; 32 | 33 | 34 | create unique index t1_pk on t1(id) pctfree 99; 35 | alter table t1 add constraint t1_pk primary key(id); 36 | 37 | execute dbms_stats.gather_table_stats(user,'t1') 38 | 39 | spool core_dc_activity_03.lst 40 | 41 | execute snap_my_stats.start_snap 42 | 43 | prompt ======================= 44 | prompt Literal string approach 45 | prompt ======================= 46 | 47 | execute snap_my_stats.start_snap 48 | 49 | declare 50 | m_n number; 51 | m_v varchar2(10); 52 | begin 53 | for i in 1..1000 loop 54 | 55 | execute immediate 56 | 'select n1 from t1 where id = ' || i 57 | into m_n; 58 | 59 | end loop; 60 | end; 61 | / 62 | 63 | execute snap_my_stats.end_snap 64 | 65 | 66 | prompt ====================== 67 | prompt Bind Variable approach 68 | prompt ====================== 69 | 70 | execute snap_my_stats.start_snap 71 | 72 | declare 73 | m_n number; 74 | begin 75 | for i in 1..1000 loop 76 | 77 | execute immediate 78 | 'select n1 from t1 where id = :n' 79 | into m_n using i; 80 | /* 81 | execute immediate 82 | 'select n1 from t1 where padding = rpad(''x'',100) and id = :n' 83 | into m_n using i; 84 | */ 85 | end loop; 86 | end; 87 | / 88 | 89 | execute snap_my_stats.end_snap 90 | 91 | spool off 92 | 93 | set doc off 94 | doc 95 | 96 | 97 | # 98 | -------------------------------------------------------------------------------- /ch_07/setenv.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: setenv.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: June 2002 5 | rem Purpose: Set up various SQL*Plus formatting commands. 6 | rem 7 | rem Notes: 8 | rem 9 | 10 | set pause off 11 | 12 | rem 13 | rem If you want to call dbms_xplan.display_cursor() to get the 14 | rem place for the last statement you executed you will have to 15 | rem set serveroutput off 16 | rem 17 | 18 | set serveroutput on size 1000000 format wrapped 19 | 20 | rem 21 | rem I'd like to enable java output, but it seems 22 | rem to push the UGA up by about 4MB when I do it 23 | rem 24 | 25 | rem execute dbms_java.set_output(1000000) 26 | 27 | rem 28 | rem Reminder about DOC, and using the # to end DOC 29 | rem the SET command stops doc material from appearing 30 | rem 31 | 32 | execute dbms_random.seed(0) 33 | 34 | set doc off 35 | doc 36 | 37 | end doc is marked with # 38 | 39 | # 40 | 41 | set linesize 120 42 | set trimspool on 43 | set pagesize 24 44 | set arraysize 25 45 | 46 | -- set longchunksize 32768 47 | -- set long 32768 48 | 49 | set autotrace off 50 | 51 | clear breaks 52 | ttitle off 53 | btitle off 54 | 55 | column owner format a15 56 | column segment_name format a20 57 | column table_name format a20 58 | column index_name format a20 59 | column object_name format a20 60 | column subobject_name format a20 61 | column partition_name format a20 62 | column subpartition_name format a20 63 | column column_name format a20 64 | column column_expression format a40 word wrap 65 | column constraint_name format a20 66 | 67 | column referenced_name format a30 68 | 69 | column file_name format a60 70 | 71 | column low_value format a24 72 | column high_value format a24 73 | 74 | column parent_id_plus_exp format 999 75 | column id_plus_exp format 990 76 | column plan_plus_exp format a90 77 | column object_node_plus_exp format a14 78 | column other_plus_exp format a90 79 | column other_tag_plus_exp format a29 80 | 81 | column access_predicates format a80 82 | column filter_predicates format a80 83 | column projection format a80 84 | column remarks format a80 85 | column partition_start format a12 86 | column partition_stop format a12 87 | column partition_id format 999 88 | column other_tag format a32 89 | column object_alias format a24 90 | 91 | column object_node format a13 92 | column other format a150 93 | 94 | column os_username format a30 95 | column terminal format a24 96 | column userhost format a24 97 | column client_id format a24 98 | 99 | column statistic_name format a35 100 | 101 | column namespace format a20 102 | column attribute format a20 103 | 104 | column hint format a40 105 | 106 | column start_time format a25 107 | column end_time format a25 108 | 109 | column time_now noprint new_value m_timestamp 110 | 111 | set feedback off 112 | 113 | select to_char(sysdate,'hh24miss') time_now from dual; 114 | commit; 115 | 116 | set feedback on 117 | 118 | set timing off 119 | set verify off 120 | 121 | alter session set optimizer_mode = all_rows; 122 | 123 | spool log 124 | 125 | -------------------------------------------------------------------------------- /ch_07/snap_11_latch.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_11_latch.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: Jan 2008 5 | rem Purpose: Package to get snapshot start and delta of latch stats 6 | rem 7 | rem Notes 8 | rem Version 11 specific 9 | rem Has to be run by SYS to create the package 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 168 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap 16 | rem -- do something 17 | rem execute snap_latch.end_snap 18 | rem 19 | rem We only capture sleep1 to sleep3 as the rest are fake columns 20 | rem and do not (appear to) capture any data. 21 | rem 22 | rem We could consider not selecting the latch name in the main 23 | rem cursor, and use the latch number to get the latch name from 24 | rem x$kslld at print time, as this would reduce the memory demand 25 | rem of the package 26 | rem 27 | 28 | create or replace package snap_latch as 29 | procedure start_snap; 30 | procedure end_snap( 31 | i_limit in number default 0, 32 | i_all_sleeps in boolean default false 33 | ); 34 | end; 35 | / 36 | 37 | create or replace package body snap_latch as 38 | 39 | cursor c1 is 40 | select 41 | lt.kslltnum indx, 42 | lt.kslltnam name, 43 | lt.ksllthsh, 44 | lt.kslltwgt gets, 45 | lt.kslltwff misses, 46 | lt.kslltwsl sleeps, 47 | lt.kslltngt immediate_gets, 48 | lt.kslltnfa immediate_misses, 49 | lt.kslltwkc waiters_woken, 50 | lt.kslltwth waits_holding_latch, 51 | lt.ksllthst0 spin_gets, 52 | lt.ksllthst1 sleep1, 53 | lt.ksllthst2 sleep2, 54 | lt.ksllthst3 sleep3, 55 | lt.kslltwtt/1000 wait_time 56 | from 57 | x$kslltr lt 58 | order by 59 | lt.kslltnum 60 | ; 61 | 62 | 63 | type w_type is table of c1%rowtype index by binary_integer; 64 | w_list w_type; 65 | w_empty_list w_type; 66 | 67 | m_start_time date; 68 | m_start_flag char(1); 69 | m_end_time date; 70 | 71 | procedure start_snap is 72 | begin 73 | 74 | m_start_time := sysdate; 75 | m_start_flag := 'U'; 76 | w_list := w_empty_list; 77 | 78 | for r in c1 loop 79 | w_list(r.indx).gets := r.gets; 80 | w_list(r.indx).misses := r.misses; 81 | w_list(r.indx).sleeps := r.sleeps; 82 | w_list(r.indx).sleep1 := r.sleep1; 83 | w_list(r.indx).sleep2 := r.sleep2; 84 | w_list(r.indx).sleep3 := r.sleep3; 85 | w_list(r.indx).spin_gets := r.spin_gets; 86 | w_list(r.indx).immediate_gets := r.immediate_gets; 87 | w_list(r.indx).immediate_misses := r.immediate_misses; 88 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 89 | w_list(r.indx).waiters_woken := r.waiters_woken; 90 | w_list(r.indx).wait_time := r.wait_time; 91 | end loop; 92 | 93 | end start_snap; 94 | 95 | 96 | procedure end_snap( 97 | i_limit in number default 0, 98 | i_all_sleeps in boolean default false 99 | ) 100 | is 101 | begin 102 | 103 | m_end_time := sysdate; 104 | 105 | dbms_output.put_line('---------------------------------'); 106 | dbms_output.put_line('Latch waits:- ' || 107 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 108 | ); 109 | 110 | if m_start_flag = 'U' then 111 | dbms_output.put_line('Interval:- ' || 112 | trunc(86400 * (m_end_time - m_start_time)) || 113 | ' seconds' 114 | ); 115 | else 116 | dbms_output.put_line('Since Startup:- ' || 117 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 118 | ); 119 | end if; 120 | 121 | if (i_limit != 0) then 122 | dbms_output.put_line('Lower limit:- ' || i_limit); 123 | end if; 124 | 125 | dbms_output.put_line('---------------------------------'); 126 | 127 | dbms_output.put( 128 | rpad('Latch',24) || 129 | lpad('Gets',15) || 130 | lpad('Misses',12) || 131 | lpad('Sp_Get',11) || 132 | lpad('Sleeps',11) 133 | ); 134 | 135 | if (i_all_sleeps) then 136 | dbms_output.put( 137 | lpad('Sleep1',11) || 138 | lpad('Sleep2',11) || 139 | lpad('Sleep3',11) 140 | ); 141 | end if; 142 | 143 | dbms_output.put_line( 144 | lpad('Im_Gets',12) || 145 | lpad('Im_Miss',10) || 146 | lpad('Holding',8) || 147 | lpad('Woken',6) || 148 | lpad('Time ms',8) 149 | ); 150 | 151 | dbms_output.put( 152 | rpad('-----',24) || 153 | lpad('----',15) || 154 | lpad('------',12) || 155 | lpad('------',11) || 156 | lpad('------',11) 157 | ); 158 | 159 | if (i_all_sleeps) then 160 | dbms_output.put( 161 | lpad('------',11) || 162 | lpad('------',11) || 163 | lpad('------',11) 164 | ); 165 | end if; 166 | 167 | dbms_output.put_line( 168 | lpad('-------',12) || 169 | lpad('-------',10) || 170 | lpad('-------',8) || 171 | lpad('-----',6) || 172 | lpad('-------',8) 173 | ); 174 | 175 | for r in c1 loop 176 | if (not w_list.exists(r.indx)) then 177 | w_list(r.indx).gets := 0; 178 | w_list(r.indx).misses := 0; 179 | w_list(r.indx).sleeps := 0; 180 | w_list(r.indx).sleep1 := 0; 181 | w_list(r.indx).sleep2 := 0; 182 | w_list(r.indx).sleep3 := 0; 183 | w_list(r.indx).spin_gets := 0; 184 | w_list(r.indx).immediate_gets := 0; 185 | w_list(r.indx).immediate_misses := 0; 186 | w_list(r.indx).waits_holding_latch := 0; 187 | w_list(r.indx).waiters_woken := 0; 188 | w_list(r.indx).wait_time := 0; 189 | end if; 190 | 191 | if ( 192 | (r.gets > w_list(r.indx).gets + i_limit) 193 | or (r.immediate_gets > w_list(r.indx).immediate_gets + i_limit) 194 | or (r.wait_time > w_list(r.indx).wait_time + i_limit) 195 | /* 196 | or (w_list(r.indx).misses != r.misses) 197 | or (w_list(r.indx).sleeps != r.sleeps) 198 | or (w_list(r.indx).sleep1 != r.sleep1) 199 | or (w_list(r.indx).sleep2 != r.sleep2) 200 | or (w_list(r.indx).sleep3 != r.sleep3) 201 | or (w_list(r.indx).spin_gets != r.spin_gets) 202 | or (w_list(r.indx).immediate_misses != r.immediate_misses) 203 | or (w_list(r.indx).waits_holding_latch != r.waits_holding_latch) 204 | or (w_list(r.indx).waiters_woken != r.waiters_woken) 205 | */ 206 | ) then 207 | 208 | dbms_output.put(rpad(substr(r.name,1,24),24)); 209 | dbms_output.put(to_char( 210 | r.gets - w_list(r.indx).gets, 211 | '99,999,999,990') 212 | ); 213 | dbms_output.put(to_char( 214 | r.misses - w_list(r.indx).misses, 215 | '999,999,990') 216 | ); 217 | dbms_output.put(to_char( 218 | r.spin_gets - w_list(r.indx).spin_gets, 219 | '99,999,990') 220 | ); 221 | dbms_output.put(to_char( 222 | r.sleeps - w_list(r.indx).sleeps, 223 | '99,999,990') 224 | ); 225 | 226 | if (i_all_sleeps) then 227 | dbms_output.put(to_char( 228 | r.sleep1 - w_list(r.indx).sleep1, 229 | '99,999,990') 230 | ); 231 | dbms_output.put(to_char( 232 | r.sleep2 - w_list(r.indx).sleep2, 233 | '99,999,990') 234 | ); 235 | dbms_output.put(to_char( 236 | r.sleep3 - w_list(r.indx).sleep3, 237 | '99,999,990') 238 | ); 239 | end if; 240 | 241 | dbms_output.put(to_char( 242 | r.immediate_gets - w_list(r.indx).immediate_gets, 243 | '999,999,990') 244 | ); 245 | dbms_output.put(to_char( 246 | r.immediate_misses - w_list(r.indx).immediate_misses, 247 | '9,999,990') 248 | ); 249 | dbms_output.put(to_char( 250 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 251 | '999,990') 252 | ); 253 | dbms_output.put(to_char( 254 | r.waiters_woken - w_list(r.indx).waiters_woken, 255 | '9,990') 256 | ); 257 | dbms_output.put(to_char( 258 | r.wait_time - w_list(r.indx).wait_time, 259 | '9,999.0') 260 | ); 261 | dbms_output.new_line; 262 | end if; 263 | 264 | end loop; 265 | 266 | 267 | end end_snap; 268 | 269 | begin 270 | select 271 | startup_time, 'S' 272 | into 273 | m_start_time, m_start_flag 274 | from 275 | v$instance; 276 | 277 | end snap_latch; 278 | / 279 | 280 | 281 | drop public synonym snap_latch; 282 | create public synonym snap_latch for snap_latch; 283 | grant execute on snap_latch to public; 284 | -------------------------------------------------------------------------------- /ch_07/snap_9_latch.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_latch.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of latch stats 6 | rem 7 | rem Notes 8 | rem Version 9/10 specific - remove references to wait_time for version 8 9 | rem Has to be run by SYS to create the package 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 168 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap 16 | rem -- do something 17 | rem execute snap_latch.end_snap 18 | rem 19 | rem We only capture sleep1 to sleep3 as the rest are fake columns 20 | rem and do not (appear to) capture any data. 21 | rem 22 | rem We could consider not selecting the latch name in the main 23 | rem cursor, and use the latch number to get the latch name from 24 | rem x$kslld at print time, as this would reduce the memory demand 25 | rem of the package 26 | rem 27 | 28 | create or replace package snap_latch as 29 | procedure start_snap; 30 | procedure end_snap( 31 | i_limit in number default 0, 32 | i_all_sleeps in boolean default false 33 | ); 34 | end; 35 | / 36 | 37 | create or replace package body snap_latch as 38 | 39 | cursor c1 is 40 | select 41 | la.latch# indx, 42 | d.kslldnam name, 43 | la.gets, 44 | la.misses, 45 | la.sleeps, 46 | la.sleep1, 47 | la.sleep2, 48 | la.sleep3, 49 | la.immediate_gets, 50 | la.immediate_misses, 51 | la.spin_gets, 52 | la.waits_holding_latch, 53 | la.waiters_woken, 54 | round(la.wait_time/1000,1) wait_time 55 | from 56 | x$kslld d, 57 | ( 58 | select 59 | kslltnum latch#, 60 | sum(kslltwgt) gets, 61 | sum(kslltwff) misses, 62 | sum(kslltwsl) sleeps, 63 | sum(kslltngt) immediate_gets, 64 | sum(kslltnfa) immediate_misses, 65 | sum(kslltwkc) waiters_woken, 66 | sum(kslltwth) waits_holding_latch, 67 | sum(ksllthst0) spin_gets, 68 | sum(ksllthst1) sleep1, 69 | sum(ksllthst2) sleep2, 70 | sum(ksllthst3) sleep3, 71 | sum(kslltwtt) wait_time 72 | from 73 | x$ksllt 74 | group by kslltnum 75 | ) la 76 | where la.latch# = d.indx 77 | order by 78 | la.latch# 79 | ; 80 | 81 | 82 | type w_type is table of c1%rowtype index by binary_integer; 83 | w_list w_type; 84 | w_empty_list w_type; 85 | 86 | m_start_time date; 87 | m_start_flag char(1); 88 | m_end_time date; 89 | 90 | procedure start_snap is 91 | begin 92 | 93 | m_start_time := sysdate; 94 | m_start_flag := 'U'; 95 | w_list := w_empty_list; 96 | 97 | for r in c1 loop 98 | w_list(r.indx).gets := r.gets; 99 | w_list(r.indx).misses := r.misses; 100 | w_list(r.indx).sleeps := r.sleeps; 101 | w_list(r.indx).sleep1 := r.sleep1; 102 | w_list(r.indx).sleep2 := r.sleep2; 103 | w_list(r.indx).sleep3 := r.sleep3; 104 | w_list(r.indx).spin_gets := r.spin_gets; 105 | w_list(r.indx).immediate_gets := r.immediate_gets; 106 | w_list(r.indx).immediate_misses := r.immediate_misses; 107 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 108 | w_list(r.indx).waiters_woken := r.waiters_woken; 109 | w_list(r.indx).wait_time := r.wait_time; 110 | end loop; 111 | 112 | end start_snap; 113 | 114 | 115 | procedure end_snap( 116 | i_limit in number default 0, 117 | i_all_sleeps in boolean default false 118 | ) 119 | is 120 | begin 121 | 122 | m_end_time := sysdate; 123 | 124 | dbms_output.put_line('---------------------------------'); 125 | dbms_output.put_line('Latch waits:- ' || 126 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 127 | ); 128 | 129 | if m_start_flag = 'U' then 130 | dbms_output.put_line('Interval:- ' || 131 | trunc(86400 * (m_end_time - m_start_time)) || 132 | ' seconds' 133 | ); 134 | else 135 | dbms_output.put_line('Since Startup:- ' || 136 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 137 | ); 138 | end if; 139 | 140 | if (i_limit != 0) then 141 | dbms_output.put_line('Lower limit:- ' || i_limit); 142 | end if; 143 | 144 | dbms_output.put_line('---------------------------------'); 145 | 146 | dbms_output.put( 147 | rpad('Latch',24) || 148 | lpad('Gets',15) || 149 | lpad('Misses',12) || 150 | lpad('Sp_Get',11) || 151 | lpad('Sleeps',11) 152 | ); 153 | 154 | if (i_all_sleeps) then 155 | dbms_output.put( 156 | lpad('Sleep1',11) || 157 | lpad('Sleep2',11) || 158 | lpad('Sleep3',11) 159 | ); 160 | end if; 161 | 162 | dbms_output.put_line( 163 | lpad('Im_Gets',12) || 164 | lpad('Im_Miss',10) || 165 | lpad('Holding',8) || 166 | lpad('Woken',6) || 167 | lpad('Time ms',8) 168 | ); 169 | 170 | dbms_output.put( 171 | rpad('-----',24) || 172 | lpad('----',15) || 173 | lpad('------',12) || 174 | lpad('------',11) || 175 | lpad('------',11) 176 | ); 177 | 178 | if (i_all_sleeps) then 179 | dbms_output.put( 180 | lpad('------',11) || 181 | lpad('------',11) || 182 | lpad('------',11) 183 | ); 184 | end if; 185 | 186 | dbms_output.put_line( 187 | lpad('-------',12) || 188 | lpad('-------',10) || 189 | lpad('-------',8) || 190 | lpad('-----',6) || 191 | lpad('-------',8) 192 | ); 193 | 194 | for r in c1 loop 195 | if (not w_list.exists(r.indx)) then 196 | w_list(r.indx).gets := 0; 197 | w_list(r.indx).misses := 0; 198 | w_list(r.indx).sleeps := 0; 199 | w_list(r.indx).sleep1 := 0; 200 | w_list(r.indx).sleep2 := 0; 201 | w_list(r.indx).sleep3 := 0; 202 | w_list(r.indx).spin_gets := 0; 203 | w_list(r.indx).immediate_gets := 0; 204 | w_list(r.indx).immediate_misses := 0; 205 | w_list(r.indx).waits_holding_latch := 0; 206 | w_list(r.indx).waiters_woken := 0; 207 | w_list(r.indx).wait_time := 0; 208 | end if; 209 | 210 | if ( 211 | (r.gets > w_list(r.indx).gets + i_limit) 212 | or (r.immediate_gets > w_list(r.indx).immediate_gets + i_limit) 213 | or (r.wait_time > w_list(r.indx).wait_time + i_limit) 214 | /* 215 | or (w_list(r.indx).misses != r.misses) 216 | or (w_list(r.indx).sleeps != r.sleeps) 217 | or (w_list(r.indx).sleep1 != r.sleep1) 218 | or (w_list(r.indx).sleep2 != r.sleep2) 219 | or (w_list(r.indx).sleep3 != r.sleep3) 220 | or (w_list(r.indx).spin_gets != r.spin_gets) 221 | or (w_list(r.indx).immediate_misses != r.immediate_misses) 222 | or (w_list(r.indx).waits_holding_latch != r.waits_holding_latch) 223 | or (w_list(r.indx).waiters_woken != r.waiters_woken) 224 | */ 225 | ) then 226 | 227 | dbms_output.put(rpad(substr(r.name,1,24),24)); 228 | dbms_output.put(to_char( 229 | r.gets - w_list(r.indx).gets, 230 | '99,999,999,990') 231 | ); 232 | dbms_output.put(to_char( 233 | r.misses - w_list(r.indx).misses, 234 | '999,999,990') 235 | ); 236 | dbms_output.put(to_char( 237 | r.spin_gets - w_list(r.indx).spin_gets, 238 | '99,999,990') 239 | ); 240 | dbms_output.put(to_char( 241 | r.sleeps - w_list(r.indx).sleeps, 242 | '99,999,990') 243 | ); 244 | 245 | if (i_all_sleeps) then 246 | dbms_output.put(to_char( 247 | r.sleep1 - w_list(r.indx).sleep1, 248 | '99,999,990') 249 | ); 250 | dbms_output.put(to_char( 251 | r.sleep2 - w_list(r.indx).sleep2, 252 | '99,999,990') 253 | ); 254 | dbms_output.put(to_char( 255 | r.sleep3 - w_list(r.indx).sleep3, 256 | '99,999,990') 257 | ); 258 | end if; 259 | 260 | dbms_output.put(to_char( 261 | r.immediate_gets - w_list(r.indx).immediate_gets, 262 | '999,999,990') 263 | ); 264 | dbms_output.put(to_char( 265 | r.immediate_misses - w_list(r.indx).immediate_misses, 266 | '9,999,990') 267 | ); 268 | dbms_output.put(to_char( 269 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 270 | '999,990') 271 | ); 272 | dbms_output.put(to_char( 273 | r.waiters_woken - w_list(r.indx).waiters_woken, 274 | '9,990') 275 | ); 276 | dbms_output.put(to_char( 277 | r.wait_time - w_list(r.indx).wait_time, 278 | '9,999.0') 279 | ); 280 | dbms_output.new_line; 281 | end if; 282 | 283 | end loop; 284 | 285 | 286 | end end_snap; 287 | 288 | begin 289 | select 290 | startup_time, 'S' 291 | into 292 | m_start_time, m_start_flag 293 | from 294 | v$instance; 295 | 296 | end snap_latch; 297 | / 298 | 299 | 300 | drop public synonym snap_latch; 301 | create public synonym snap_latch for snap_latch; 302 | grant execute on snap_latch to public; 303 | -------------------------------------------------------------------------------- /ch_07/snap_9_latch_child.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_9_latch_child.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of latch child stats 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Version 9/10 specific - remove references to wait_time for version 8 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_latch.start_snap_cbc 16 | rem -- do something 17 | rem execute snap_latch.end_snap_cbc 18 | rem 19 | rem Optionally capture sleep1, sleep2, sleep3. The rest (4 - 11) 20 | rem are fake columns, not populated by Oracle 21 | rem 22 | 23 | create or replace package snap_latch_child as 24 | 25 | procedure start_snap(i_latch in varchar2); 26 | procedure end_snap(i_latch in varchar2, i_all_sleeps in boolean default false); 27 | 28 | procedure start_snap_cbc; 29 | procedure end_snap_cbc(i_all_sleeps in boolean default false); 30 | 31 | end; 32 | / 33 | 34 | create or replace package body snap_latch_child as 35 | 36 | cursor c1 (i_latch in varchar2) is 37 | select 38 | la.addr, 39 | la.child# indx, 40 | la.gets, 41 | la.misses, 42 | la.sleeps, 43 | la.sleep1, 44 | la.sleep2, 45 | la.sleep3, 46 | la.immediate_gets, 47 | la.immediate_misses, 48 | la.spin_gets, 49 | la.waits_holding_latch, 50 | la.waiters_woken, 51 | round(la.wait_time/1000,3) wait_time 52 | from 53 | v$latch_children la 54 | where la.name = i_latch 55 | order by 56 | la.child# 57 | ; 58 | 59 | type w_type is table of c1%rowtype index by binary_integer; 60 | w_list w_type; 61 | w_empty_list w_type; 62 | 63 | m_start_time date; 64 | m_start_flag char(1); 65 | m_end_time date; 66 | 67 | procedure start_snap (i_latch in varchar2) is 68 | begin 69 | 70 | m_start_time := sysdate; 71 | m_start_flag := 'U'; 72 | w_list := w_empty_list; 73 | 74 | for r in c1(i_latch) loop 75 | w_list(r.indx).gets := r.gets; 76 | w_list(r.indx).misses := r.misses; 77 | w_list(r.indx).sleeps := r.sleeps; 78 | w_list(r.indx).sleep1 := r.sleep1; 79 | w_list(r.indx).sleep2 := r.sleep2; 80 | w_list(r.indx).sleep3 := r.sleep3; 81 | w_list(r.indx).spin_gets := r.spin_gets; 82 | w_list(r.indx).immediate_gets := r.immediate_gets; 83 | w_list(r.indx).immediate_misses := r.immediate_misses; 84 | w_list(r.indx).waits_holding_latch := r.waits_holding_latch; 85 | w_list(r.indx).waiters_woken := r.waiters_woken; 86 | w_list(r.indx).wait_time := r.wait_time; 87 | end loop; 88 | 89 | 90 | end start_snap; 91 | 92 | 93 | procedure end_snap(i_latch in varchar2, i_all_sleeps in boolean default false) is 94 | 95 | m_latch_count number(6) := 0; 96 | begin 97 | 98 | 99 | m_end_time := sysdate; 100 | 101 | dbms_output.put_line('---------------------------------------------------------'); 102 | dbms_output.put_line(i_latch || ' latch waits - ' || 103 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 104 | ); 105 | 106 | if m_start_flag = 'U' then 107 | dbms_output.put_line('Interval:- ' || 108 | trunc(86400 * (m_end_time - m_start_time)) || 109 | ' seconds' 110 | ); 111 | else 112 | dbms_output.put_line('Since Startup:- ' || 113 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 114 | ); 115 | end if; 116 | 117 | dbms_output.put_line('---------------------------------------------------------'); 118 | 119 | dbms_output.put( 120 | rpad('Address',17) || 121 | lpad('Gets',15) || 122 | lpad('Misses',12) || 123 | lpad('Spins',11) || 124 | lpad('Sleeps',11) 125 | ); 126 | 127 | if (i_all_sleeps) then 128 | dbms_output.put( 129 | lpad('Sleep1',11) || 130 | lpad('Sleep2',11) || 131 | lpad('Sleep3',11) 132 | ); 133 | end if; 134 | 135 | dbms_output.put_line( 136 | lpad('Im_Gets',14) || 137 | lpad('Im_Miss',12) || 138 | lpad('Holding',8) || 139 | lpad('Woken',6) || 140 | lpad('Time m/s',12) 141 | ); 142 | 143 | dbms_output.put( 144 | rpad('-------',17) || 145 | lpad('----',15) || 146 | lpad('------',12) || 147 | lpad('------',11) || 148 | lpad('-----',11) 149 | ); 150 | 151 | if (i_all_sleeps) then 152 | dbms_output.put( 153 | lpad('-----',11) || 154 | lpad('-----',11) || 155 | lpad('------',11) 156 | ); 157 | end if; 158 | 159 | dbms_output.put_line( 160 | lpad('-------',14) || 161 | lpad('-------',12) || 162 | lpad('-------',8) || 163 | lpad('-----',6) || 164 | lpad('--------',12) 165 | ); 166 | 167 | for r in c1(i_latch) loop 168 | if (not w_list.exists(r.indx)) then 169 | w_list(r.indx).gets := 0; 170 | w_list(r.indx).misses := 0; 171 | w_list(r.indx).sleeps := 0; 172 | w_list(r.indx).sleep1 := 0; 173 | w_list(r.indx).sleep2 := 0; 174 | w_list(r.indx).sleep3 := 0; 175 | w_list(r.indx).spin_gets := 0; 176 | w_list(r.indx).immediate_gets := 0; 177 | w_list(r.indx).immediate_misses := 0; 178 | w_list(r.indx).waits_holding_latch := 0; 179 | w_list(r.indx).waiters_woken := 0; 180 | w_list(r.indx).wait_time := 0; 181 | end if; 182 | 183 | if ( 184 | w_list(r.indx).gets != r.gets 185 | or w_list(r.indx).misses != r.misses 186 | or w_list(r.indx).sleeps != r.sleeps 187 | or w_list(r.indx).sleep1 != r.sleep1 188 | or w_list(r.indx).sleep2 != r.sleep2 189 | or w_list(r.indx).sleep3 != r.sleep3 190 | or w_list(r.indx).spin_gets != r.spin_gets 191 | or w_list(r.indx).immediate_gets != r.immediate_gets 192 | or w_list(r.indx).immediate_misses != r.immediate_misses 193 | or w_list(r.indx).waits_holding_latch != r.waits_holding_latch 194 | or w_list(r.indx).waiters_woken != r.waiters_woken 195 | or w_list(r.indx).wait_time != r.wait_time 196 | ) then 197 | m_latch_count := m_latch_count + 1; 198 | 199 | dbms_output.put(rpad(r.addr,17)); 200 | dbms_output.put(to_char( 201 | r.gets - w_list(r.indx).gets, 202 | '99,999,999,990') 203 | ); 204 | dbms_output.put(to_char( 205 | r.misses - w_list(r.indx).misses, 206 | '999,999,990') 207 | ); 208 | dbms_output.put(to_char( 209 | r.spin_gets - w_list(r.indx).spin_gets, 210 | '99,999,990') 211 | ); 212 | dbms_output.put(to_char( 213 | r.sleeps - w_list(r.indx).sleeps, 214 | '99,999,990') 215 | ); 216 | 217 | if (i_all_sleeps) then 218 | dbms_output.put(to_char( 219 | r.sleep1 - w_list(r.indx).sleep1, 220 | '99,999,990') 221 | ); 222 | dbms_output.put(to_char( 223 | r.sleep2 - w_list(r.indx).sleep2, 224 | '99,999,990') 225 | ); 226 | dbms_output.put(to_char( 227 | r.sleep3 - w_list(r.indx).sleep3, 228 | '99,999,990') 229 | ); 230 | end if; 231 | 232 | dbms_output.put(to_char( 233 | r.immediate_gets - w_list(r.indx).immediate_gets, 234 | '9,999,999,990') 235 | ); 236 | dbms_output.put(to_char( 237 | r.immediate_misses - w_list(r.indx).immediate_misses, 238 | '999,999,990') 239 | ); 240 | dbms_output.put(to_char( 241 | r.waits_holding_latch - w_list(r.indx).waits_holding_latch, 242 | '999,990') 243 | ); 244 | dbms_output.put(to_char( 245 | r.waiters_woken - w_list(r.indx).waiters_woken, 246 | '9,990') 247 | ); 248 | dbms_output.put(to_char( 249 | r.wait_time - w_list(r.indx).wait_time, 250 | '999,999.990') 251 | ); 252 | dbms_output.new_line; 253 | end if; 254 | 255 | end loop; 256 | 257 | dbms_output.put_line('Latches reported: ' || m_latch_count); 258 | 259 | end end_snap; 260 | 261 | procedure start_snap_cbc is 262 | begin 263 | start_snap('cache buffers chains'); 264 | end; 265 | 266 | procedure end_snap_cbc(i_all_sleeps in boolean default false) is 267 | begin 268 | end_snap('cache buffers chains', i_all_sleeps); 269 | end; 270 | 271 | begin 272 | select 273 | startup_time, 'S' 274 | into 275 | m_start_time, m_start_flag 276 | from 277 | v$instance; 278 | 279 | end snap_latch_child; 280 | / 281 | 282 | 283 | drop public synonym snap_latch_child; 284 | create public synonym snap_latch_child for snap_latch_child; 285 | grant execute on snap_latch_child to public; 286 | -------------------------------------------------------------------------------- /ch_07/snap_myst.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_myst.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of v$mystat 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem Depends on view v$my_stats (see c_mystats.sql) 10 | rem 11 | rem Usage: 12 | rem set serveroutput on size 1000000 format wrapped 13 | rem set linesize 120 14 | rem set trimspool on 15 | rem execute snap_my_stats.start_snap 16 | rem -- do something 17 | rem execute snap_my_stats.end_snap 18 | rem 19 | 20 | create or replace package snap_my_stats as 21 | procedure start_snap; 22 | procedure end_snap (i_limit in number default 0); 23 | end; 24 | / 25 | 26 | create or replace package body snap_my_stats as 27 | 28 | cursor c1 is 29 | select 30 | statistic#, 31 | name, 32 | value 33 | from 34 | v$my_stats 35 | where 36 | value != 0 37 | ; 38 | 39 | 40 | type w_type is table of c1%rowtype index by binary_integer; 41 | w_list w_type; 42 | empty_list w_type; 43 | 44 | m_start_time date; 45 | m_start_flag char(1); 46 | m_end_time date; 47 | 48 | procedure start_snap is 49 | begin 50 | 51 | m_start_time := sysdate; 52 | m_start_flag := 'U'; 53 | w_list := empty_list; 54 | 55 | for r in c1 loop 56 | w_list(r.statistic#).value := r.value; 57 | end loop; 58 | 59 | end start_snap; 60 | 61 | 62 | 63 | procedure end_snap (i_limit in number default 0) 64 | is 65 | begin 66 | 67 | m_end_time := sysdate; 68 | 69 | dbms_output.put_line('---------------------------------'); 70 | dbms_output.put_line('Session stats - ' || 71 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 72 | ); 73 | 74 | if m_start_flag = 'U' then 75 | dbms_output.put_line('Interval:- ' || 76 | trunc(86400 * (m_end_time - m_start_time)) || 77 | ' seconds' 78 | ); 79 | else 80 | dbms_output.put_line('Since Startup:- ' || 81 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 82 | ); 83 | end if; 84 | 85 | if (i_limit != 0) then 86 | dbms_output.put_line('Lower limit:- ' || i_limit); 87 | end if; 88 | 89 | dbms_output.put_line('---------------------------------'); 90 | 91 | dbms_output.put_line( 92 | rpad('Name',60) || 93 | lpad('Value',18) 94 | ); 95 | 96 | dbms_output.put_line( 97 | rpad('----',60) || 98 | lpad('-----',18) 99 | ); 100 | 101 | for r in c1 loop 102 | if (not w_list.exists(r.statistic#)) then 103 | w_list(r.statistic#).value := 0; 104 | end if; 105 | 106 | if ( 107 | (r.value > w_list(r.statistic#).value + i_limit) 108 | ) then 109 | dbms_output.put(rpad(r.name,60)); 110 | dbms_output.put(to_char( 111 | r.value - w_list(r.statistic#).value, 112 | '9,999,999,999,990') 113 | ); 114 | dbms_output.new_line; 115 | end if; 116 | end loop; 117 | 118 | end end_snap; 119 | 120 | begin 121 | select 122 | logon_time, 'S' 123 | into 124 | m_start_time, m_start_flag 125 | from 126 | v$session 127 | where 128 | sid = ( 129 | select /*+ no_unnest */ sid 130 | from v$mystat 131 | where rownum = 1 132 | ); 133 | 134 | end snap_my_stats; 135 | / 136 | 137 | 138 | drop public synonym snap_my_stats; 139 | create public synonym snap_my_stats for snap_my_stats; 140 | grant execute on snap_my_stats to public; 141 | -------------------------------------------------------------------------------- /ch_07/snap_rowcache.sql: -------------------------------------------------------------------------------- 1 | rem 2 | rem Script: snap_rowcache.sql 3 | rem Author: Jonathan Lewis 4 | rem Dated: March 2001 5 | rem Purpose: Package to get snapshot start and delta of rowcache 6 | rem 7 | rem Notes 8 | rem Has to be run by SYS to create the package 9 | rem 10 | rem Usage: 11 | rem set serveroutput on size 1000000 format wrapped 12 | rem set linesize 120 13 | rem set trimspool on 14 | rem execute snap_rowcache.start_snap 15 | rem -- do something 16 | rem execute snap_rowcache.end_snap 17 | rem 18 | rem To be enhanced - 19 | rem There are several caches with the same cache#, but 20 | rem different subordinate#. Should show the subordinate# 21 | rem to emphasize the difference 22 | rem 23 | 24 | create or replace package snap_rowcache as 25 | procedure start_snap; 26 | procedure end_snap; 27 | end; 28 | / 29 | 30 | create or replace package body snap_rowcache as 31 | 32 | cursor c1 is 33 | select 34 | indx indx, 35 | inst_id instance, 36 | kqrstcid cache#, 37 | decode(kqrsttyp,1,'PARENT','SUBORDINATE') dc_type, 38 | decode(kqrsttyp,2,kqrstsno,null) subordinate#, 39 | kqrsttxt parameter, 40 | kqrstcsz dc_count, 41 | kqrstosz o_size, 42 | kqrstusg usage, 43 | kqrstfcs fixed, 44 | kqrstgrq gets, 45 | kqrstgmi misses, 46 | kqrstsrq scans, 47 | kqrstsmi scanmisses, 48 | kqrstsco scancompletes, 49 | kqrstmrq modifications, 50 | kqrstmfl flushes, 51 | kqrstilr dlm_requests, 52 | kqrstifr dlm_conflicts, 53 | kqrstisr dlm_releases 54 | from 55 | x$kqrst 56 | ; 57 | 58 | 59 | type w_type1 is table of c1%rowtype index by binary_integer; 60 | w_list1 w_type1; 61 | w_empty_list w_type1; 62 | 63 | m_start_time date; 64 | m_start_flag char(1); 65 | m_end_time date; 66 | 67 | procedure start_snap is 68 | begin 69 | 70 | m_start_time := sysdate; 71 | m_start_flag := 'U'; 72 | w_list1 := w_empty_list; 73 | 74 | for r in c1 loop 75 | w_list1(r.indx).usage := r.usage; 76 | w_list1(r.indx).fixed := r.fixed; 77 | w_list1(r.indx).gets := r.gets; 78 | w_list1(r.indx).misses := r.misses; 79 | w_list1(r.indx).scans := r.scans; 80 | w_list1(r.indx).scanmisses := r.scanmisses; 81 | w_list1(r.indx).scancompletes := r.scancompletes; 82 | w_list1(r.indx).modifications := r.modifications; 83 | w_list1(r.indx).flushes := r.flushes; 84 | end loop; 85 | 86 | end start_snap; 87 | 88 | 89 | procedure end_snap is 90 | begin 91 | 92 | m_end_time := sysdate; 93 | 94 | dbms_output.put_line('---------------------------------'); 95 | dbms_output.put_line('Dictionary Cache - ' || 96 | to_char(m_end_time,'dd-Mon hh24:mi:ss') 97 | ); 98 | 99 | if m_start_flag = 'U' then 100 | dbms_output.put_line('Interval:- ' || 101 | trunc(86400 * (m_end_time - m_start_time)) || 102 | ' seconds' 103 | ); 104 | else 105 | dbms_output.put_line('Since Startup:- ' || 106 | to_char(m_start_time,'dd-Mon hh24:mi:ss') 107 | ); 108 | end if; 109 | 110 | dbms_output.put_line('---------------------------------'); 111 | 112 | dbms_output.put_line( 113 | rpad('Parameter',25) || 114 | lpad('Usage',6) || 115 | lpad('Fixed',6) || 116 | lpad('Gets',8) || 117 | lpad('Misses',8) || 118 | lpad('Scans',8) || 119 | lpad('Misses',8) || 120 | lpad('Comp',8) || 121 | lpad('Mods',8) || 122 | lpad('Flushes',8) 123 | ); 124 | 125 | dbms_output.put_line( 126 | rpad('---------',25) || 127 | lpad('-----',6) || 128 | lpad('-----',6) || 129 | lpad('----',8) || 130 | lpad('------',8) || 131 | lpad('-----',8) || 132 | lpad('------',8) || 133 | lpad('--------',8) || 134 | lpad('----',8) || 135 | lpad('-------',8) 136 | ); 137 | 138 | for r in c1 loop 139 | if (not w_list1.exists(r.indx)) then 140 | w_list1(r.indx).usage := 0; 141 | w_list1(r.indx).fixed := 0; 142 | w_list1(r.indx).gets := 0; 143 | w_list1(r.indx).misses := 0; 144 | w_list1(r.indx).scans := 0; 145 | w_list1(r.indx).scanmisses := 0; 146 | w_list1(r.indx).scancompletes := 0; 147 | w_list1(r.indx).modifications := 0; 148 | w_list1(r.indx).flushes := 0; 149 | end if; 150 | 151 | if ( 152 | w_list1(r.indx).usage != r.usage 153 | or w_list1(r.indx).fixed != r.fixed 154 | or w_list1(r.indx).gets != r.gets 155 | or w_list1(r.indx).misses != r.misses 156 | or w_list1(r.indx).scans != r.scans 157 | or w_list1(r.indx).scanmisses != r.scanmisses 158 | or w_list1(r.indx).scancompletes != r.scancompletes 159 | or w_list1(r.indx).modifications != r.modifications 160 | or w_list1(r.indx).flushes != r.flushes 161 | ) then 162 | 163 | dbms_output.put(rpad(substr(r.parameter,1,25),25)); 164 | dbms_output.put(to_char( 165 | r.usage - w_list1(r.indx).usage, 166 | '9,990') 167 | ); 168 | dbms_output.put(to_char( 169 | r.fixed - w_list1(r.indx).fixed, 170 | '9,990') 171 | ); 172 | dbms_output.put(to_char( 173 | r.gets - w_list1(r.indx).gets, 174 | '999,990') 175 | ); 176 | dbms_output.put(to_char( 177 | r.misses - w_list1(r.indx).misses, 178 | '999,990') 179 | ); 180 | dbms_output.put(to_char( 181 | r.scans - w_list1(r.indx).scans, 182 | '999,990') 183 | ); 184 | dbms_output.put(to_char( 185 | r.scanmisses - w_list1(r.indx).scanmisses, 186 | '999,990') 187 | ); 188 | dbms_output.put(to_char( 189 | r.scancompletes - w_list1(r.indx).scancompletes, 190 | '999,990') 191 | ); 192 | dbms_output.put(to_char( 193 | r.modifications - w_list1(r.indx).modifications, 194 | '999,990') 195 | ); 196 | dbms_output.put(to_char( 197 | r.flushes - w_list1(r.indx).flushes, 198 | '999,990') 199 | ); 200 | dbms_output.new_line; 201 | 202 | end if; 203 | 204 | end loop; 205 | 206 | end end_snap; 207 | 208 | begin 209 | select 210 | startup_time, 'S' 211 | into 212 | m_start_time, m_start_flag 213 | from 214 | v$instance; 215 | 216 | end snap_rowcache; 217 | / 218 | 219 | 220 | drop public synonym snap_rowcache; 221 | create public synonym snap_rowcache for snap_rowcache; 222 | grant execute on snap_rowcache to public; 223 | -------------------------------------------------------------------------------- /contributing.md: -------------------------------------------------------------------------------- 1 | # Contributing to Apress Source Code 2 | 3 | Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers. 4 | 5 | ## How to Contribute 6 | 7 | 1. Make sure you have a GitHub account. 8 | 2. Fork the repository for the relevant book. 9 | 3. Create a new branch on which to make your change, e.g. 10 | `git checkout -b my_code_contribution` 11 | 4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted. 12 | 5. Submit a pull request. 13 | 14 | Thank you for your contribution! --------------------------------------------------------------------------------