|
| 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; |
0 commit comments