前往小程序,Get更优阅读体验!
立即前往
首页
学习
活动
专区
工具
TVP
发布
社区首页 >专栏 >【Oracle】-【show_space和show_space_asm】-执行存储过程show_space和show_space_asm报错

【Oracle】-【show_space和show_space_asm】-执行存储过程show_space和show_space_asm报错

作者头像
bisal
发布2019-01-29 10:23:10
1.3K0
发布2019-01-29 10:23:10
举报

Sys建立show_space()和show_space_asm()。

Bisal执行提示:

SQL> exec show_space('MY_OBJECTS', 'BISAL');

BEGIN show_space('MY_OBJECTS', 'BISAL'); END;

      *

ERROR at line 1:

ORA-06550: line 1, column 7:

PLS-00201: identifier 'SHOW_SPACE' must be declared

ORA-06550: line 1, column 7:

PL/SQL: Statement ignored

Sys用户执行:grant execute on show_space to bisal,bisal还是无法执行。

Sys用户执行:

SQL> create public synonym show_space for sys.show_space;   

Synonym created.

SQL> grant execute on show_space to public ;

Grant succeeded.

Bisal执行:

SQL> exec show_space('MY_OBJECTS', 'BISAL');

UNFORMATTED BLOCKS .....................        0

FS1 BLOCKS (0-25) ......................        0

FS2 BLOCKS (25-50) .....................        0

FS3 BLOCKS (50-75) .....................       18

FS4 BLOCKS (75-100).....................      122

FULL BLOCKS ............................        0

TOTAL BLOCKS............................      256

TOTAL BYTES.............................       2,097,152

TOTAL MBYTES............................        2

UNUSED BLOCKS...........................      104

UNUSED BYTES............................  851,968

LAST USED EXT FILEID....................        5

LAST USED EXT BLOCKID...................      137

LAST USED BLOCK.........................       24

PL/SQL procedure successfully completed.

SQL> exec show_space_assm('MY_OBJECTS', 'BISAL');

free space 0-25% Blocks:................0

free space 25-50% Blocks:...............0

free space 50-75% Blocks:...............18

free space 75-100% Blocks:..............122

Full Blocks:............................0

Unformatted blocks:.....................0

PL/SQL procedure successfully completed.

附TOM大神的show_space和show_space_assm:

  1. -- -----------------------------------------------------------------------------------
  2. -- Author : Tom Kyte
  3. -- Description : Displays free and unused space for the specified object.
  4. -- Call Syntax : EXEC Show_Space('Tablename');
  5. -- Requirements : SET SERVEROUTPUT ON 
  6. -- Last Modified: June 22, 2010
  7. -- This enhance version has all the fixes for ASSM, LMT, partitions etc (Oracle version 10gr2 +)
  8. -- -----------------------------------------------------------------------------------
  9. set define off
  10. create or replace procedure show_space
  11. ( p_segname in varchar2,
  12.  p_owner in varchar2 default user,
  13.  p_type in varchar2 default 'TABLE',
  14.  p_partition in varchar2 default NULL )
  15. -- this procedure uses authid current user so it can query DBA_*
  16. -- views using privileges from a ROLE and so it can be installed
  17. -- once per database, instead of once per user that wanted to use it
  18. authid current_user
  19. as
  20.     l_free_blks number;
  21.     l_total_blocks number;
  22.     l_total_bytes number;
  23.     l_unused_blocks number;
  24.     l_unused_bytes number;
  25.     l_LastUsedExtFileId number;
  26.     l_LastUsedExtBlockId number;
  27.     l_LAST_USED_BLOCK number;
  28.     l_segment_space_mgmt varchar2(255);
  29.     l_unformatted_blocks number;
  30.     l_unformatted_bytes number;
  31.     l_fs1_blocks number; l_fs1_bytes number;
  32.     l_fs2_blocks number; l_fs2_bytes number;
  33.     l_fs3_blocks number; l_fs3_bytes number;
  34.     l_fs4_blocks number; l_fs4_bytes number;
  35.     l_full_blocks number; l_full_bytes number;
  36. -- inline procedure to print out numbers nicely formatted
  37. -- with a simple label
  38.     procedure p( p_label in varchar2, p_num in number )
  39. is
  40. begin
  41.        dbms_output.put_line( rpad(p_label,40,'.') ||
  42. to_char(p_num,'999,999,999,999') );
  43. end;
  44. begin
  45. -- this query is executed dynamically in order to allow this procedure
  46. -- to be created by a user who has access to DBA_SEGMENTS/TABLESPACES
  47. -- via a role as is customary.
  48. -- NOTE: at runtime, the invoker MUST have access to these two
  49. -- views!
  50. -- this query determines if the object is a ASSM object or not
  51. begin
  52. execute immediate
  53. 'select ts.segment_space_management
  54.             from dba_segments seg, dba_tablespaces ts
  55.            where seg.segment_name = :p_segname
  56.              and (:p_partition is null or
  57.                  seg.partition_name = :p_partition)
  58.              and seg.owner = :p_owner
  59.              and seg.segment_type = :p_type
  60.              and seg.tablespace_name = ts.tablespace_name'
  61. into l_segment_space_mgmt
  62. using p_segname, p_partition, p_partition, p_owner, p_type;
  63.   exception
  64.       when too_many_rows then
  65.          dbms_output.put_line
  66. ( 'This must be a partitioned table, use p_partition => ');
  67. return;
  68. end;
  69. -- if the object is in an ASSM tablespace, we must use this API
  70. -- call to get space information, else we use the FREE_BLOCKS
  71. -- API for the user managed segments
  72. if l_segment_space_mgmt = 'AUTO'
  73. then
  74.     dbms_space.space_usage
  75. ( p_owner, p_segname, p_type, l_unformatted_blocks,
  76.       l_unformatted_bytes, l_fs1_blocks, l_fs1_bytes,
  77.       l_fs2_blocks, l_fs2_bytes, l_fs3_blocks, l_fs3_bytes,
  78.       l_fs4_blocks, l_fs4_bytes, l_full_blocks, l_full_bytes, p_partition);
  79.     p( 'Unformatted Blocks ', l_unformatted_blocks );
  80.     p( 'FS1 Blocks (0-25) ', l_fs1_blocks );
  81.     p( 'FS2 Blocks (25-50) ', l_fs2_blocks );
  82.     p( 'FS3 Blocks (50-75) ', l_fs3_blocks );
  83.     p( 'FS4 Blocks (75-100)', l_fs4_blocks );
  84.     p( 'Full Blocks ', l_full_blocks );
  85. else
  86.     dbms_space.free_blocks(
  87.       segment_owner => p_owner,
  88.       segment_name => p_segname,
  89.       segment_type => p_type,
  90.       freelist_group_id => 0,
  91.       free_blks => l_free_blks);
  92.     p( 'Free Blocks', l_free_blks );
  93. end if;
  94. -- and then the unused space API call to get the rest of the
  95. -- information
  96.  dbms_space.unused_space
  97. ( segment_owner => p_owner,
  98.     segment_name => p_segname,
  99.     segment_type => p_type,
  100.     partition_name => p_partition,
  101.     total_blocks => l_total_blocks,
  102.     total_bytes => l_total_bytes,
  103.     unused_blocks => l_unused_blocks,
  104.     unused_bytes => l_unused_bytes,
  105.     LAST_USED_EXTENT_FILE_ID => l_LastUsedExtFileId,
  106.     LAST_USED_EXTENT_BLOCK_ID => l_LastUsedExtBlockId,
  107.     LAST_USED_BLOCK => l_LAST_USED_BLOCK );
  108.     p( 'Total Blocks', l_total_blocks );
  109.     p( 'Total Bytes', l_total_bytes );
  110.     p( 'Total MBytes', trunc(l_total_bytes/1024/1024) );
  111.     p( 'Unused Blocks', l_unused_blocks );
  112.     p( 'Unused Bytes', l_unused_bytes );
  113.     p( 'Last Used Ext FileId', l_LastUsedExtFileId );
  114.     p( 'Last Used Ext BlockId', l_LastUsedExtBlockId );
  115.     p( 'Last Used Block', l_LAST_USED_BLOCK );
  116. end;
  117. /
  118. set define on

create or replace procedure show_space_assm( p_segname in varchar2, p_owner in varchar2 default user, p_type in varchar2 default 'TABLE' ) as l_fs1_bytes number; l_fs2_bytes number; l_fs3_bytes number; l_fs4_bytes number; l_fs1_blocks number; l_fs2_blocks number; l_fs3_blocks number; l_fs4_blocks number; l_full_bytes number; l_full_blocks number; l_unformatted_bytes number; l_unformatted_blocks number; procedure p( p_label in varchar2, p_num in number ) is begin dbms_output.put_line( rpad(p_label,40,'.') ||p_num ); end; begin dbms_space.space_usage( segment_owner => p_owner, segment_name => p_segname, segment_type => p_type, fs1_bytes => l_fs1_bytes, fs1_blocks => l_fs1_blocks, fs2_bytes => l_fs2_bytes, fs2_blocks => l_fs2_blocks, fs3_bytes => l_fs3_bytes, fs3_blocks => l_fs3_blocks, fs4_bytes => l_fs4_bytes, fs4_blocks => l_fs4_blocks, full_bytes => l_full_bytes, full_blocks => l_full_blocks, unformatted_blocks => l_unformatted_blocks, unformatted_bytes => l_unformatted_bytes); p('free space 0-25% Blocks:',l_fs1_blocks); p('free space 25-50% Blocks:',l_fs2_blocks); p('free space 50-75% Blocks:',l_fs3_blocks); p('free space 75-100% Blocks:',l_fs4_blocks); p('Full Blocks:',l_full_blocks); p('Unformatted blocks:',l_unformatted_blocks); end;

/

本文参与 腾讯云自媒体分享计划,分享自作者个人站点/博客。
原始发表:2013年07月14日,如有侵权请联系 cloudcommunity@tencent.com 删除

本文分享自 作者个人站点/博客 前往查看

如有侵权,请联系 cloudcommunity@tencent.com 删除。

本文参与 腾讯云自媒体分享计划  ,欢迎热爱写作的你一起参与!

评论
登录后参与评论
0 条评论
热度
最新
推荐阅读
领券
问题归档专栏文章快讯文章归档关键词归档开发者手册归档开发者手册 Section 归档