show_space
?
??? Tom的show_space備份一下。非常有用!!!
?
?
CREATE OR REPLACE PROCEDURE show_space(p_segname IN VARCHAR2,
?????????????????????????????????????? p_owner IN VARCHAR2 DEFAULT 'USER',
?????????????????????????????????????? p_type IN VARCHAR2 DEFAULT 'TABLE',
?????????????????????????????????????? p_partition IN VARCHAR2 DEFAULT NULL
?????????????????????????????????????? )
AUTHID CURRENT_USER
AS
? l_free_blks ??? NUMBER;
? l_total_blocks NUMBER;
? l_total_bytes ? NUMBER;
? l_unused_blocks NUMBER;
? l_unused_bytes NUMBER;
? l_lastusedextfileid NUMBER;
? l_lastusedextblockid NUMBER;
? l_last_used_block ?? NUMBER;
?????????????????????????????????????? p_owner IN VARCHAR2 DEFAULT 'USER',
?????????????????????????????????????? p_type IN VARCHAR2 DEFAULT 'TABLE',
?????????????????????????????????????? p_partition IN VARCHAR2 DEFAULT NULL
?????????????????????????????????????? )
AUTHID CURRENT_USER
AS
? l_free_blks ??? NUMBER;
? l_total_blocks NUMBER;
? l_total_bytes ? NUMBER;
? l_unused_blocks NUMBER;
? l_unused_bytes NUMBER;
? l_lastusedextfileid NUMBER;
? l_lastusedextblockid NUMBER;
? l_last_used_block ?? NUMBER;
? PROCEDURE p (p_label IN VARCHAR2, p_num IN NUMBER)
? IS
? BEGIN
??? DBMS_OUTPUT.put_line (RPAD (p_label, 40, '.') || p_num);
? END;
? IS
? BEGIN
??? DBMS_OUTPUT.put_line (RPAD (p_label, 40, '.') || p_num);
? END;
BEGIN
? FOR x IN (SELECT tablespace_name
????????????? FROM user_tablespaces
???????????? WHERE tablespace_name =
?????????????????? (SELECT tablespace_name
????????????????????? FROM user_segments
???????????????????? WHERE segment_type = p_type
?????????????????????? AND segment_name = p_segname
?????????????????????? AND segment_space_management <> 'AUTO'))
? LOOP
??? DBMS_SPACE.free_blocks (segment_owner => p_owner,
??????????????????????????? segment_name => p_segname,
??????????????????????????? segment_type => p_type,
??????????????????????????? partition_name => p_partition,
??????????????????????????? freelist_group_id => 0,
??????????????????????????? free_blks => l_free_blks
??????????????????????????? );
? END LOOP;
? DBMS_SPACE.unused_space (segment_owner => p_owner,
?????????????????????????? segment_name => p_segname,
?????????????????????????? segment_type => p_type,
?????????????????????????? partition_name => p_partition,
?????????????????????????? total_blocks => l_total_blocks,
?????????????????????????? total_bytes => l_total_bytes,
?????????????????????????? unused_blocks => l_unused_blocks,
?????????????????????????? unused_bytes => l_unused_bytes,
?????????????????????????? last_used_extent_file_id => l_lastusedextfileid,
?????????????????????????? last_used_extent_block_id => l_lastusedextblockid,
?????????????????????????? last_used_block => l_last_used_block
?????????????????????????? );
?????????????????????????? segment_name => p_segname,
?????????????????????????? segment_type => p_type,
?????????????????????????? partition_name => p_partition,
?????????????????????????? total_blocks => l_total_blocks,
?????????????????????????? total_bytes => l_total_bytes,
?????????????????????????? unused_blocks => l_unused_blocks,
?????????????????????????? unused_bytes => l_unused_bytes,
?????????????????????????? last_used_extent_file_id => l_lastusedextfileid,
?????????????????????????? last_used_extent_block_id => l_lastusedextblockid,
?????????????????????????? last_used_block => l_last_used_block
?????????????????????????? );
? p ('Free Blocks', l_free_blks);
? p ('Total Blocks', l_total_blocks);
? p ('Total Bytes', l_total_bytes);
? p ('Total MBytes', TRUNC (l_total_bytes / 1024 / 1024));
? p ('Unused Blocks', l_unused_blocks);
? p ('Unused Bytes', l_unused_bytes);
? p ('Last Used Ext FileId', l_lastusedextfileid);
? p ('Last Used Ext BlockId', l_lastusedextblockid);
? p ('Last Used Block', l_last_used_block);
END;
/
? p ('Total Blocks', l_total_blocks);
? p ('Total Bytes', l_total_bytes);
? p ('Total MBytes', TRUNC (l_total_bytes / 1024 / 1024));
? p ('Unused Blocks', l_unused_blocks);
? p ('Unused Bytes', l_unused_bytes);
? p ('Last Used Ext FileId', l_lastusedextfileid);
? p ('Last Used Ext BlockId', l_lastusedextblockid);
? p ('Last Used Block', l_last_used_block);
END;
/
?
??? 修改后支持 ASSM 的 show_space script
?
?
create or replaceprocedure show_space(p_segname_1 in varchar2,
??????????????????????????????????????? p_space in varchar2 default 'MANUAL',
??????????????????????????????????????? p_type_1 in varchar2 default 'TABLE' ,
??????????????????????????????????????? p_freespace in varchar2 default 'N',
??????????????????????????????????????? p_owner_1 in varchar2 default user)
as
? p_segname varchar2(100);
? p_type ?? varchar2(10);
? p_owner ? varchar2(30);
??????????????????????????????????????? p_space in varchar2 default 'MANUAL',
??????????????????????????????????????? p_type_1 in varchar2 default 'TABLE' ,
??????????????????????????????????????? p_freespace in varchar2 default 'N',
??????????????????????????????????????? p_owner_1 in varchar2 default user)
as
? p_segname varchar2(100);
? p_type ?? varchar2(10);
? p_owner ? varchar2(30);
?
? l_unformatted_blocks number;
? l_unformatted_bytes number;
? l_fs1_blocks number;
? l_fs1_bytes number;
? l_fs2_blocks number;
? l_fs2_bytes number;
? l_fs3_blocks number;
? l_fs3_bytes number;
? l_fs4_blocks number;
? l_fs4_bytes number;
? l_full_blocks number;
? l_full_bytes number;
? l_unformatted_bytes number;
? l_fs1_blocks number;
? l_fs1_bytes number;
? l_fs2_blocks number;
? l_fs2_bytes number;
? l_fs3_blocks number;
? l_fs3_bytes number;
? l_fs4_blocks number;
? l_fs4_bytes number;
? l_full_blocks number;
? l_full_bytes number;
?
? l_free_blks number;
? l_total_blocks number;
? l_total_bytes number;
? l_unused_blocks number;
? l_unused_bytes number;
? l_LastUsedExtFileId number;
? l_LastUsedExtBlockId number;
? l_LAST_USED_BLOCK number;
? l_total_blocks number;
? l_total_bytes number;
? l_unused_blocks number;
? l_unused_bytes number;
? l_LastUsedExtFileId number;
? l_LastUsedExtBlockId number;
? l_LAST_USED_BLOCK number;
?
? procedure p( p_label in varchar2, p_num in number )
? is
? begin
??? dbms_output.put_line( rpad(p_label,40,'.') ||p_num );
? end;
? is
? begin
??? dbms_output.put_line( rpad(p_label,40,'.') ||p_num );
? end;
begin
? p_segname := upper(p_segname_1); -- rainy changed?
? p_owner := upper(p_owner_1);
? p_type := p_type_1;
? p_segname := upper(p_segname_1); -- rainy changed?
? p_owner := upper(p_owner_1);
? p_type := p_type_1;
?
? if (p_type_1 = 'i' or p_type_1 = 'I') then --rainy changed
??? p_type := 'INDEX';
? end if;
??? p_type := 'INDEX';
? end if;
?
? if (p_type_1 = 't' or p_type_1 = 'T') then --rainy changed
??? p_type := 'TABLE';
? end if;
??? p_type := 'TABLE';
? end if;
?
? if (p_type_1 = 'c' or p_type_1 = 'C') then --rainy changed
??? p_type := 'CLUSTER';
? end if;
??? p_type := 'CLUSTER';
? end if;
? dbms_space.unused_space(segment_owner => p_owner,
?????????????????????????? segment_name => p_segname,
?????????????????????????? segment_type => p_type,
?????????????????????????? total_blocks => l_total_blocks,
?????????????????????????? total_bytes => l_total_bytes,
?????????????????????????? unused_blocks => l_unused_blocks,
?????????????????????????? unused_bytes => l_unused_bytes,
?????????????????????????? LAST_USED_EXTENT_FILE_ID => l_LastUsedExtFileId,
?????????????????????????? LAST_USED_EXTENT_BLOCK_ID => l_LastUsedExtBlockId,
?????????????????????????? LAST_USED_BLOCK => l_LAST_USED_BLOCK );
?
? if p_space = 'MANUAL' or (p_space <> 'auto' and p_space <> 'AUTO') then
??? dbms_space.free_blocks(segment_owner => p_owner,
??????????????????????????? segment_name => p_segname,
??????????????????????????? segment_type => p_type,
??????????????????????????? freelist_group_id => 0,
??????????????????????????? free_blks => l_free_blks );
??? dbms_space.free_blocks(segment_owner => p_owner,
??????????????????????????? segment_name => p_segname,
??????????????????????????? segment_type => p_type,
??????????????????????????? freelist_group_id => 0,
??????????????????????????? free_blks => l_free_blks );
?
??? p( 'Free Blocks', l_free_blks );
? end if;
? end if;
? p( 'Total Blocks', l_total_blocks );
? p( 'Total Bytes', l_total_bytes );
? p( 'Unused Blocks', l_unused_blocks );
? p( 'Unused Bytes', l_unused_bytes );
? p( 'Last Used Ext FileId', l_LastUsedExtFileId );
? p( 'Last Used Ext BlockId', l_LastUsedExtBlockId );
? p( 'Last Used Block', l_LAST_USED_BLOCK );
?
? if p_freespace = 'Y' then
??? dbms_space.space_usage(segment_owner => p_owner ,
??????????????????????????? segment_name => p_segname ,
??????????????????????????? segment_type => p_type ,
??????????????????????????? unformatted_blocks => l_unformatted_blocks ,
??????????????????????????? unformatted_bytes => l_unformatted_bytes,
??????????????????????????? fs1_blocks => l_fs1_blocks,
??????????????????????????? fs1_bytes => l_fs1_bytes ,
??????????????????????????? fs2_blocks => l_fs2_blocks,
??????????????????????????? fs2_bytes => l_fs2_bytes,
??????????????????????????? fs3_blocks => l_fs3_blocks ,
??????????????????????????? fs3_bytes => l_fs3_bytes,
??????????????????????????? fs4_blocks => l_fs4_blocks,
??????????????????????????? fs4_bytes => l_fs4_bytes,
??????????????????????????? full_blocks => l_full_blocks,
??????????????????????????? full_bytes => l_full_bytes);
??? dbms_space.space_usage(segment_owner => p_owner ,
??????????????????????????? segment_name => p_segname ,
??????????????????????????? segment_type => p_type ,
??????????????????????????? unformatted_blocks => l_unformatted_blocks ,
??????????????????????????? unformatted_bytes => l_unformatted_bytes,
??????????????????????????? fs1_blocks => l_fs1_blocks,
??????????????????????????? fs1_bytes => l_fs1_bytes ,
??????????????????????????? fs2_blocks => l_fs2_blocks,
??????????????????????????? fs2_bytes => l_fs2_bytes,
??????????????????????????? fs3_blocks => l_fs3_blocks ,
??????????????????????????? fs3_bytes => l_fs3_bytes,
??????????????????????????? fs4_blocks => l_fs4_blocks,
??????????????????????????? fs4_bytes => l_fs4_bytes,
??????????????????????????? full_blocks => l_full_blocks,
??????????????????????????? full_bytes => l_full_bytes);
??? dbms_output.put_line(rpad(' ',50,'*'));
??? p( '0% -- 25% free space blocks', l_fs1_blocks);
??? p( '0% -- 25% free space bytes', l_fs1_bytes);
??? p( '25% -- 50% free space blocks', l_fs2_blocks);
??? p( '25% -- 50% free space bytes', l_fs2_bytes);
??? p( '50% -- 75% free space blocks', l_fs3_blocks);
??? p( '50% -- 75% free space bytes', l_fs3_bytes);
??? p( '75% -- 100% free space blocks', l_fs4_blocks);
??? p( '75% -- 100% free space bytes', l_fs4_bytes);
??? p( 'Unused Blocks', l_unformatted_blocks );
??? p( 'Unused Bytes', l_unformatted_bytes );
??? p( 'Total Blocks', l_full_blocks);
??? p( 'Total bytes', l_full_bytes);
??? p( '0% -- 25% free space bytes', l_fs1_bytes);
??? p( '25% -- 50% free space blocks', l_fs2_blocks);
??? p( '25% -- 50% free space bytes', l_fs2_bytes);
??? p( '50% -- 75% free space blocks', l_fs3_blocks);
??? p( '50% -- 75% free space bytes', l_fs3_bytes);
??? p( '75% -- 100% free space blocks', l_fs4_blocks);
??? p( '75% -- 100% free space bytes', l_fs4_bytes);
??? p( 'Unused Blocks', l_unformatted_blocks );
??? p( 'Unused Bytes', l_unformatted_bytes );
??? p( 'Total Blocks', l_full_blocks);
??? p( 'Total bytes', l_full_bytes);
?
? end if;
?
end;
/
?
?
ASSM 類型的表:
?
SQL> exec show_space('t','auto');
Total Blocks............................512
Total Bytes.............................4194304
Unused Blocks...........................78
Unused Bytes............................638976
Last Used Ext FileId....................9
Last Used Ext BlockId...................25608
Last Used Block.........................50
Total Blocks............................512
Total Bytes.............................4194304
Unused Blocks...........................78
Unused Bytes............................638976
Last Used Ext FileId....................9
Last Used Ext BlockId...................25608
Last Used Block.........................50
?
PL/SQL procedure successfully completed.
?
?
ASSM 類型的索引:
SQL> exec show_space('t_index','auto','i');
Total Blocks............................80
Total Bytes.............................655360
Unused Blocks...........................5
Unused Bytes............................40960
Last Used Ext FileId....................9
Last Used Ext BlockId...................25312
Last Used Block.........................3
?
PL/SQL procedure successfully completed.
?
?
?
SQL> exec show_space('t','auto','T','Y');
Total Blocks............................512
Total Bytes.............................4194304
Unused Blocks...........................78
Unused Bytes............................638976
Last Used Ext FileId....................9
Last Used Ext BlockId...................25608
Last Used Block.........................50
*************************************************
0% -- 25% free space blocks.............0
0% -- 25% free space bytes..............0
25% -- 50% free space blocks............0
25% -- 50% free space bytes.............0
50% -- 75% free space blocks............0
50% -- 75% free space bytes.............0
75% -- 100% free space blocks...........0
75% -- 100% free space bytes............0
Unused Blocks...........................0
Unused Bytes............................0
Total Blocks............................418
Total bytes.............................3424256
Total Blocks............................512
Total Bytes.............................4194304
Unused Blocks...........................78
Unused Bytes............................638976
Last Used Ext FileId....................9
Last Used Ext BlockId...................25608
Last Used Block.........................50
*************************************************
0% -- 25% free space blocks.............0
0% -- 25% free space bytes..............0
25% -- 50% free space blocks............0
25% -- 50% free space bytes.............0
50% -- 75% free space blocks............0
50% -- 75% free space bytes.............0
75% -- 100% free space blocks...........0
75% -- 100% free space bytes............0
Unused Blocks...........................0
Unused Bytes............................0
Total Blocks............................418
Total bytes.............................3424256
?
PL/SQL procedure successfully completed.
?
?