Oracle数据库数据恢复、性能优化

找回密码
注册
搜索
热搜: 活动 交友 discuz
发新帖

39

积分

0

好友

5

主题
1#
发表于 2011-12-7 17:25:22 | 查看: 13016| 回复: 16
ml你好:  我发现在在一个aix上的oracle 10.2.0.3的库上,system表空间大小已经达到7g多,但是实际查询dba_segments视图一共才占用300多m,resize datafile也降不下来,查了下hwm也是在7g多的位置上,system表空间也没有非系统用户的对象,以前这个表是自动扩展的,但是通过查询dba_data_files发现bytes和user_bytes都大于maxsize的值,现在已经改成非自动扩展,请问这个情况该如何降低hwm来回收空间? 谢谢!
  1. select * from dba_data_files where tablespace_name='SYSTEM';

  2.           FILE_NAME        FILE_ID        TABLESPACE_NAME        BYTES        BLOCKS        STATUS        RELATIVE_FNO        AUTOEXTENSIBLE        MAXBYTES        MAXBLOCKS        INCREMENT_BY        USER_BYTES        USER_BLOCKS        ONLINE_STATUS
  3. 1        /oradata/orcl/system01.dbf        1        SYSTEM        7864320000        960000        AVAILABLE        1        NO        0        0        0        7864254464        959992        SYSTEM

  4. select owner,count(*) from dba_SEGMENTs where tablespace_name='SYSTEM' group by owner

  5.            OWNER        COUNT(*)
  6. 1        SYSTEM        246
  7. 2        SYS        951
  8. 3        OUTLN        8

  9. select round(sum(bytes)/1024/1024/1024,2) from dba_segments where tablespace_name='SYSTEM';

  10.            ROUND(SUM(BYTES)/1024/1024/102
  11. 1        0.33

  12.            表空间名        表空间大小(M)        已使用空间(M)        使用百分比        空闲空间(M)
  13. 9        SYSTEM        7500        339           4.52        7161

  14. select max(block_id)*8/1024 "m size" from dba_extents where tablespace_name='SYSTEM'

  15. 7362.0703125
复制代码
2#
发表于 2011-12-8 00:11:40
action plan:

运行以下SQL语句:
  1. REM tablespace report

  2. set linesize 200

  3. select a.tablespace_name,
  4.        round(a.bytes_alloc / 1024 / 1024) megs_alloc,
  5.        round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
  6.        round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
  7.        round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
  8.        100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
  9.        round(maxbytes / 1048576) Max
  10.   from (select f.tablespace_name,
  11.                sum(f.bytes) bytes_alloc,
  12.                sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
  13.           from dba_data_files f
  14.          group by tablespace_name) a,
  15.        (select f.tablespace_name, sum(f.bytes) bytes_free
  16.           from dba_free_space f
  17.          group by tablespace_name) b
  18. where a.tablespace_name = b.tablespace_name(+)
  19. union all
  20. select h.tablespace_name,
  21.        round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
  22.        round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  23.              1048576) megs_free,
  24.        round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
  25.        round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  26.              sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
  27.        100 -
  28.        round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  29.              sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
  30.        round(sum(f.maxbytes) / 1048576) max
  31.   from sys.v_$TEMP_SPACE_HEADER h,
  32.        sys.v_$Temp_extent_pool  p,
  33.        dba_temp_files           f
  34. where p.file_id(+) = h.file_id
  35.    and p.tablespace_name(+) = h.tablespace_name
  36.    and f.file_id = h.file_id
  37.    and f.tablespace_name = h.tablespace_name
  38. group by h.tablespace_name
  39. ORDER BY 1
  40. /

  41.     SELECT d.tablespace_name "Name",
  42.                 TO_CHAR(NVL(a.bytes / 1024 / 1024, 0),'99,999,990.900') "Size (M)",
  43.                 TO_CHAR(NVL(t.hwm, 0)/1024/1024,'99999999.999')  "HWM (M)",
  44.                 TO_CHAR(NVL(t.hwm / a.bytes * 100, 0), '990.00') "HWM % " ,
  45.                 TO_CHAR(NVL(t.bytes/1024/1024, 0),'99999999.999') "Using (M)",
  46.                 TO_CHAR(NVL(t.bytes / a.bytes * 100, 0), '990.00') "Using %"
  47.            FROM sys.dba_tablespaces d,
  48.                 (select tablespace_name, sum(bytes) bytes from dba_temp_files group by tablespace_name) a,
  49.                 (select tablespace_name, sum(bytes_cached) hwm, sum(bytes_used) bytes from v$temp_extent_pool group by tablespace_name) t
  50.           WHERE d.tablespace_name = a.tablespace_name(+)
  51.             AND d.tablespace_name = t.tablespace_name(+)
  52.             AND d.extent_management like 'LOCAL'
  53.             AND d.contents like 'TEMPORARY'
  54. /

  55. ttitle -
  56.    center  'Database Freespace Summary'  skip 2

  57. comp sum of nfrags totsiz avasiz on report
  58. break on report

  59. set pages 999
  60. col tsname  format     a16 justify c heading 'Tablespace'
  61. col nfrags  format 999,990 justify c heading 'Free|Frags'
  62. col mxfrag  format 999,999 justify c heading 'Largest|Frag (MB)'
  63. col totsiz  format 999,999 justify c heading 'Total|(MB)'
  64. col avasiz  format 999,999 justify c heading 'Available|(MB)'
  65. col pctusd  format     990 justify c heading 'Pct|Used'

  66. select total.TABLESPACE_NAME tsname,
  67.        D nfrags,
  68.        C/1024/1024 mxfrag,
  69.        A/1024/1024 totsiz,
  70.        B/1024/1024 avasiz,
  71.        (1-nvl(B,0)/A)*100 pctusd
  72. from
  73.     (select sum(bytes) A,
  74.             tablespace_name
  75.             from dba_data_files
  76.             group by tablespace_name) TOTAL,
  77.     (select sum(bytes) B,
  78.             max(bytes) C,
  79.             count(bytes) D,
  80.             tablespace_name
  81.             from dba_free_space
  82.             group by tablespace_name) FREE
  83. where
  84.       total.TABLESPACE_NAME=free.TABLESPACE_NAME(+)
  85. /

  86. SELECT t.tablespace_name,
  87.        CASE
  88.          WHEN t.contents = 'TEMPORARY' AND t.extent_management = 'LOCAL' THEN
  89.           u.bytes
  90.          ELSE
  91.           df.user_bytes - NVL(fs.bytes, 0)
  92.        END / 1024 / 1024 used_mb,
  93.        CASE
  94.          WHEN t.contents = 'TEMPORARY' AND t.extent_management = 'LOCAL' THEN
  95.           df.user_bytes - NVL(u.bytes, 0)
  96.          ELSE
  97.           NVL(fs.bytes, 0)
  98.        END / 1024 / 1024 free_mb,
  99.        fs.min_fragment / 1024 / 1024 min_fragment_mb,
  100.        fs.max_fragment / 1024 / 1024 max_fragment_mb,
  101.        (fs.bytes / 1024 / 1024) / fs.fragments avg_fragment_mb,
  102.        fs.fragments,
  103.        t.status,
  104.        t.contents,
  105.        t.logging,
  106.        t.extent_management,
  107.        t.allocation_type,
  108.        t.force_logging,
  109.        t.segment_space_management,
  110.        t.def_tab_compression,
  111.        t.retention,
  112.        t.bigfile
  113.   FROM dba_tablespaces t,
  114.        (SELECT tablespace_name,
  115.                SUM(bytes) bytes,
  116.                MIN(min_fragment) min_fragment,
  117.                MAX(max_fragment) max_fragment,
  118.                SUM(fragments) fragments
  119.           FROM (SELECT tablespace_name,
  120.                        SUM(bytes) bytes,
  121.                        MIN(bytes) min_fragment,
  122.                        MAX(bytes) max_fragment,
  123.                        COUNT(*) fragments
  124.                   FROM dba_free_space
  125.                  GROUP BY tablespace_name
  126.                 UNION ALL
  127.                 SELECT tablespace_name,
  128.                        SUM(bytes) bytes,
  129.                        MIN(bytes) min_fragment,
  130.                        MAX(bytes) max_fragment,
  131.                        COUNT(*) fragments
  132.                   FROM dba_undo_extents
  133.                  WHERE status = 'EXPIRED'
  134.                  GROUP BY tablespace_name)
  135.          GROUP BY tablespace_name) fs,
  136.        (SELECT tablespace_name, SUM(user_bytes) user_bytes
  137.           FROM dba_data_files
  138.          GROUP BY tablespace_name
  139.         UNION ALL
  140.         SELECT tablespace_name, SUM(user_bytes) user_bytes
  141.           FROM dba_temp_files
  142.          GROUP BY tablespace_name) df,
  143.        (SELECT tablespace_name, SUM(bytes_used) bytes
  144.           FROM gv$temp_extent_pool
  145.          GROUP BY tablespace_name) u
  146. WHERE t.tablespace_name = df.tablespace_name(+)
  147.    AND t.tablespace_name = fs.tablespace_name(+)
  148.    AND t.tablespace_name = u.tablespace_name(+)
  149. /
复制代码
将结果上传 , 以code代码模式展示

回复 只看该作者 道具 举报

3#
发表于 2011-12-8 10:52:50

  1. SQL> REM tablespace report
  2. SQL> set linesize 200
  3. SQL> select a.tablespace_name,
  4.   2         round(a.bytes_alloc / 1024 / 1024) megs_alloc,
  5.   3         round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
  6.   4         round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
  7.   5         round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
  8.   6         100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
  9.   7         round(maxbytes / 1048576) Max
  10.   8    from (select f.tablespace_name,
  11.   9                 sum(f.bytes) bytes_alloc,
  12. 10                 sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
  13. 11            from dba_data_files f
  14. 12           group by tablespace_name) a,
  15. 13         (select f.tablespace_name, sum(f.bytes) bytes_free
  16. 14            from dba_free_space f
  17. 15           group by tablespace_name) b
  18. 16  where a.tablespace_name = b.tablespace_name(+)
  19. 17  union all
  20. 18  select h.tablespace_name,
  21. 19         round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
  22. 20         round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  23. 21               1048576) megs_free,
  24. 22         round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
  25. 23         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  26. 24               sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
  27. 25         100 -
  28. 26         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  29. 27               sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
  30. 28         round(sum(f.maxbytes) / 1048576) max
  31. 29    from sys.v_$TEMP_SPACE_HEADER h,
  32. 30         sys.v_$Temp_extent_pool  p,
  33. 31         dba_temp_files           f
  34. 32  where p.file_id(+) = h.file_id
  35. 33     and p.tablespace_name(+) = h.tablespace_name
  36. 34     and f.file_id = h.file_id
  37. 35     and f.tablespace_name = h.tablespace_name
  38. 36  group by h.tablespace_name
  39. 37  ORDER BY 1
  40. 38  /
  41. TABLESPACE_NAME                MEGS_ALLOC  MEGS_FREE  MEGS_USED   PCT_FREE   PCT_USED        MAX
  42. ------------------------------ ---------- ---------- ---------- ---------- ---------- ----------
  43. anno_122                              100          8         92          8         92      32768
  44. IM2                                 31828      13704      18124         43         57     362948
  45. IM2_INDEX                           65696       5315      60381          8         92     196608
  46. IM2_TEMP                             3096       3096          0        100          0          0
  47. IM2_TS2                               100        100          0        100          0      32768
  48. IM3WEB                                115          1        114          1         99      32768
  49. JDHXP                                 100         81         19         81         19      32768
  50. P2SYS                                 500        499          1        100          0      32768
  51. P2USER                                500        446         55         89         11      32768
  52. P3USER                                500        497          3         99          1      32768
  53. SYSAUX                                844         92        752         11         89      32768
  54. SYSTEM                               7500       7161        340         95          5       7500
  55. TEMP                                  733        733          0        100          0      32768
  56. TS_AD                                 200         44        156         22         78        200
  57. TS_EDOC                                20         20          0        100          0      32768
  58. UNDOTBS1                             9820       9617        203         98          2      32768
  59. USERS                                 500        489         11         98          2      32768
  60. 17 rows selected
  61. SQL>     SELECT d.tablespace_name "Name",
  62.   2                  TO_CHAR(NVL(a.bytes / 1024 / 1024, 0),'99,999,990.900') "Size (M)",
  63.   3                  TO_CHAR(NVL(t.hwm, 0)/1024/1024,'99999999.999')  "HWM (M)",
  64.   4                  TO_CHAR(NVL(t.hwm / a.bytes * 100, 0), '990.00') "HWM % " ,
  65.   5                  TO_CHAR(NVL(t.bytes/1024/1024, 0),'99999999.999') "Using (M)",
  66.   6                  TO_CHAR(NVL(t.bytes / a.bytes * 100, 0), '990.00') "Using %"
  67.   7             FROM sys.dba_tablespaces d,
  68.   8                  (select tablespace_name, sum(bytes) bytes from dba_temp_files group by tablespace_name) a,
  69.   9                  (select tablespace_name, sum(bytes_cached) hwm, sum(bytes_used) bytes from v$temp_extent_pool group by tablespace_name) t
  70. 10            WHERE d.tablespace_name = a.tablespace_name(+)
  71. 11              AND d.tablespace_name = t.tablespace_name(+)
  72. 12              AND d.extent_management like 'LOCAL'
  73. 13              AND d.contents like 'TEMPORARY'
  74. 14  /
  75. Name                           Size (M)        HWM (M)       HWM %   Using (M)     Using %
  76. ------------------------------ --------------- ------------- ------- ------------- -------
  77. TEMP                                   733.000       194.000   26.47          .000    0.00
  78. IM2_TEMP                             3,096.000      2778.000   89.73          .000    0.00

复制代码

回复 只看该作者 道具 举报

4#
发表于 2011-12-8 10:53:17
  1. SQL> ttitle -
  2. SQL> center 'Database Freespace Summary' skip 2
  3. SQL> comp sum of nfrags totsiz avasiz on report
  4. SQL> break on report
  5. SQL> set pages 999
  6. SQL> col tsname format a16 justify c heading 'Tablespace'
  7. SQL> col nfrags format 999,990 justify c heading 'Free|Frags'
  8. SQL> col mxfrag format 999,999 justify c heading 'Largest|Frag (MB)'
  9. SQL> col totsiz format 999,999 justify c heading 'Total|(MB)'
  10. SQL> col avasiz format 999,999 justify c heading 'Available|(MB)'
  11. SQL> col pctusd format 990 justify c heading 'Pct|Used'
  12. SQL> select total.TABLESPACE_NAME tsname,
  13. 2 D nfrags,
  14. 3 C/1024/1024 mxfrag,
  15. 4 A/1024/1024 totsiz,
  16. 5 B/1024/1024 avasiz,
  17. 6 (1-nvl(B,0)/A)*100 pctusd
  18. 7 from
  19. 8 (select sum(bytes) A,
  20. 9 tablespace_name
  21. 10 from dba_data_files
  22. 11 group by tablespace_name) TOTAL,
  23. 12 (select sum(bytes) B,
  24. 13 max(bytes) C,
  25. 14 count(bytes) D,
  26. 15 tablespace_name
  27. 16 from dba_free_space
  28. 17 group by tablespace_name) FREE
  29. 18 where
  30. 19 total.TABLESPACE_NAME=free.TABLESPACE_NAME(+)
  31. 20 /

  32. TSNAME NFRAGS MXFRAG TOTSIZ AVASIZ PCT
  33. ---------------- ---------- ---------- ---------- ---------- ---
  34. SYSTEM 5 3309.5625 7500 7160.5 4.5
  35. 266
  36. 666
  37. 666
  38. 666
  39. 7

  40. IM2_INDEX 224 277 65696 5314.5625 91.
  41. 910
  42. 371
  43. 255
  44. 479
  45. 8

  46. USERS 4 488.4375 500 488.625 2.2
  47. 75

  48. anno_122 4 8.0625 100 8.25 91.
  49. 75

  50. TS_AD 18 41.9375 200 43.5625 78.
  51. 218
  52. 75

  53. P2USER 1 445.5 500 445.5 10.
  54. 9

  55. IM2_TS2 1 99.9375 100 99.9375 0.0
  56. 625

  57. TS_EDOC 1 19.9375 20 19.9375 0.3
  58. 125

  59. IM2 171 868.9375 31828 13703.9375 56.
  60. 943
  61. 768
  62. 065
  63. 854

  64. JDHXP 2 80.9375 100 81.0625 18.
  65. 937
  66. 5

  67. IM3WEB 2 0.9375 115 1.3125 98.
  68. 858
  69. 695
  70. 652
  71. 173
  72. 9

  73. SYSAUX 50 63.3125 844 91.8125 89.
  74. 121
  75. 741
  76. 706
  77. 161
  78. 1

  79. P3USER 1 497.125 500 497.125 0.5
  80. 75

  81. UNDOTBS1 60 3968 9820 9617.1875 2.0
  82. 653
  83. 004
  84. 073
  85. 319
  86. 8

  87. P2SYS 1 499.25 500 499.25 0.1
  88. 5


  89. 15 rows selected

  90. SQL> SELECT t.tablespace_name,
  91. 2 CASE
  92. 3 WHEN t.contents = 'TEMPORARY' AND t.extent_management = 'LOCAL' THEN
  93. 4 u.bytes
  94. 5 ELSE
  95. 6 df.user_bytes - NVL(fs.bytes, 0)
  96. 7 END / 1024 / 1024 used_mb,
  97. 8 CASE
  98. 9 WHEN t.contents = 'TEMPORARY' AND t.extent_management = 'LOCAL' THEN
  99. 10 df.user_bytes - NVL(u.bytes, 0)
  100. 11 ELSE
  101. 12 NVL(fs.bytes, 0)
  102. 13 END / 1024 / 1024 free_mb,
  103. 14 fs.min_fragment / 1024 / 1024 min_fragment_mb,
  104. 15 fs.max_fragment / 1024 / 1024 max_fragment_mb,
  105. 16 (fs.bytes / 1024 / 1024) / fs.fragments avg_fragment_mb,
  106. 17 fs.fragments,
  107. 18 t.status,
  108. 19 t.contents,
  109. 20 t.logging,
  110. 21 t.extent_management,
  111. 22 t.allocation_type,
  112. 23 t.force_logging,
  113. 24 t.segment_space_management,
  114. 25 t.def_tab_compression,
  115. 26 t.retention,
  116. 27 t.bigfile
  117. 28 FROM dba_tablespaces t,
  118. 29 (SELECT tablespace_name,
  119. 30 SUM(bytes) bytes,
  120. 31 MIN(min_fragment) min_fragment,
  121. 32 MAX(max_fragment) max_fragment,
  122. 33 SUM(fragments) fragments
  123. 34 FROM (SELECT tablespace_name,
  124. 35 SUM(bytes) bytes,
  125. 36 MIN(bytes) min_fragment,
  126. 37 MAX(bytes) max_fragment,
  127. 38 COUNT(*) fragments
  128. 39 FROM dba_free_space
  129. 40 GROUP BY tablespace_name
  130. 41 UNION ALL
  131. 42 SELECT tablespace_name,
  132. 43 SUM(bytes) bytes,
  133. 44 MIN(bytes) min_fragment,
  134. 45 MAX(bytes) max_fragment,
  135. 46 COUNT(*) fragments
  136. 47 FROM dba_undo_extents
  137. 48 WHERE status = 'EXPIRED'
  138. 49 GROUP BY tablespace_name)
  139. 50 GROUP BY tablespace_name) fs,
  140. 51 (SELECT tablespace_name, SUM(user_bytes) user_bytes
  141. 52 FROM dba_data_files
  142. 53 GROUP BY tablespace_name
  143. 54 UNION ALL
  144. 55 SELECT tablespace_name, SUM(user_bytes) user_bytes
  145. 56 FROM dba_temp_files
  146. 57 GROUP BY tablespace_name) df,
  147. 58 (SELECT tablespace_name, SUM(bytes_used) bytes
  148. 59 FROM gv$temp_extent_pool
  149. 60 GROUP BY tablespace_name) u
  150. 61 WHERE t.tablespace_name = df.tablespace_name(+)
  151. 62 AND t.tablespace_name = fs.tablespace_name(+)
  152. 63 AND t.tablespace_name = u.tablespace_name(+)
  153. 64 /

  154. TABLESPACE_NAME USED_MB FREE_MB MIN_FRAGMENT_MB MAX_FRAGMENT_MB AVG_FRAGMENT_MB FRAGMENTS STATUS CONTENTS LOGGING EXTENT_MANAGEMENT ALLOCATION_TYPE FORCE_LOGGING SEGMENT_SPACE_MANAGEMENT DEF_TAB_COMPRESSION RETENTION BIGFILE
  155. ------------------------------ ---------- ---------- --------------- --------------- --------------- ---------- --------- --------- --------- ----------------- --------------- ------------- ------------------------ ------------------- ----------- -------
  156. SYSTEM 339.4375 7160.5 136.9375 3309.5625 1432.1 5 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO MANUAL DISABLED NOT APPLY NO
  157. IM2_INDEX 60381.0625 5314.5625 0.0625 277 23.725725446428 224 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  158. USERS 11.3125 488.625 0.0625 488.4375 122.15625 4 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  159. anno_122 91.6875 8.25 0.0625 8.0625 2.0625 4 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  160. TS_AD 156.375 43.5625 0.0625 41.9375 2.4201388888888 18 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  161. P2USER 54.4375 445.5 445.5 445.5 445.5 1 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  162. IM2_TS2 0 99.9375 99.9375 99.9375 99.9375 1 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  163. TS_EDOC 0 19.9375 19.9375 19.9375 19.9375 1 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  164. IM2 18123.3125 13703.9375 0.0625 868.9375 80.139985380117 171 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  165. JDHXP 18.875 81.0625 0.125 80.9375 40.53125 2 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  166. IM3WEB 113.625 1.3125 0.375 0.9375 0.65625 2 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  167. SYSAUX 752.125 91.8125 0.0625 63.3125 1.83625 50 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  168. P3USER 2.8125 497.125 497.125 497.125 497.125 1 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  169. UNDOTBS1 20.125 9799.8125 0.0625 3968 36.980424528301 265 ONLINE UNDO LOGGING LOCAL SYSTEM NO MANUAL DISABLED NOGUARANTEE NO
  170. P2SYS 0.6875 499.25 499.25 499.25 499.25 1 ONLINE PERMANENT LOGGING LOCAL SYSTEM NO AUTO DISABLED NOT APPLY NO
  171. TEMP 0 732 ONLINE TEMPORARY NOLOGGING LOCAL UNIFORM NO MANUAL DISABLED NOT APPLY NO
  172. IM2_TEMP 0 3094 ONLINE TEMPORARY NOLOGGING LOCAL UNIFORM NO MANUAL DISABLED NOT APPLY NO
复制代码

回复 只看该作者 道具 举报

5#
发表于 2011-12-8 19:52:19
你好,

就输出结果来看system表空间确实有大量空闲空间

SYSTEM                               7500       7161        340         95          5       7500


一般这些空闲空间是可以回收的  但是请注意 resize的大小 过小可能导致 ORA-03297: file contains used data beyond requested RESIZE value 错误



如:
  1. SQL> alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' autoextend on next 200M maxsize unlimited;

  2. Database altered.

  3. SQL> create table tl(t1 int) tablespace system;

  4. Table created.

  5. SQL> alter table tl allocate extent ( size 2000M);

  6. Table altered.

  7. SQL> REM tablespace report
  8. SQL>
  9. SQL> set linesize 200
  10. SQL>
  11. SQL> select a.tablespace_name,
  12.   2         round(a.bytes_alloc / 1024 / 1024) megs_alloc,
  13.   3         round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
  14.   4         round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
  15.   5         round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
  16.   6         100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
  17.   7         round(maxbytes / 1048576) Max
  18.   8    from (select f.tablespace_name,
  19.   9                 sum(f.bytes) bytes_alloc,
  20. 10                 sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
  21. 11            from dba_data_files f
  22. 12           group by tablespace_name) a,
  23. 13         (select f.tablespace_name, sum(f.bytes) bytes_free
  24. 14            from dba_free_space f
  25. 15           group by tablespace_name) b
  26. 16  where a.tablespace_name = b.tablespace_name(+)
  27. 17  union all
  28. 18  select h.tablespace_name,
  29. 19         round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
  30. 20         round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  31. 21               1048576) megs_free,
  32. 22         round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
  33. 23         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  34. 24               sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
  35. 25         100 -
  36. 26         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  37. 27               sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
  38. 28         round(sum(f.maxbytes) / 1048576) max
  39. 29    from sys.v_$TEMP_SPACE_HEADER h,
  40. 30         sys.v_$Temp_extent_pool  p,
  41. 31         dba_temp_files           f
  42. 32  where p.file_id(+) = h.file_id
  43. 33     and p.tablespace_name(+) = h.tablespace_name
  44. 34     and f.file_id = h.file_id
  45. 35     and f.tablespace_name = h.tablespace_name
  46. 36  group by h.tablespace_name
  47. 37  ORDER BY 1
  48. 38  /

  49. TABLESPACE_NAME                MEGS_ALLOC  MEGS_FREE  MEGS_USED   PCT_FREE   PCT_USED        MAX
  50. ------------------------------ ---------- ---------- ---------- ---------- ---------- ----------
  51. EXAMPLE                               171          3        168          2         98      32768
  52. SYSAUX                                310         44        266         14         86      32768
  53. SYSTEM                               5700        190       5510          3         97      32768
  54. TEMP                                 2968       2968          0        100          0      32768
  55. UNDOTBS1                             1165        825        340         71         29      32768
  56. USERS                                8985         36       8950          0        100      32768

  57. 6 rows selected.

  58. SQL> drop table tl;

  59. Table dropped.

  60. SQL> REM tablespace report
  61. SQL>
  62. SQL> set linesize 200
  63. SQL>
  64. SQL> select a.tablespace_name,
  65.   2         round(a.bytes_alloc / 1024 / 1024) megs_alloc,
  66.   3         round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
  67.   4         round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
  68.   5         round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
  69.   6         100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
  70.   7         round(maxbytes / 1048576) Max
  71.   8    from (select f.tablespace_name,
  72.   9                 sum(f.bytes) bytes_alloc,
  73. 10                 sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
  74. 11            from dba_data_files f
  75. 12           group by tablespace_name) a,
  76. 13         (select f.tablespace_name, sum(f.bytes) bytes_free
  77. 14            from dba_free_space f
  78. 15           group by tablespace_name) b
  79. 16  where a.tablespace_name = b.tablespace_name(+)
  80. 17  union all
  81. 18  select h.tablespace_name,
  82. 19         round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
  83. 20         round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  84. 21               1048576) megs_free,
  85. 22         round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
  86. 23         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  87. 24               sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
  88. 25         100 -
  89. 26         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  90. 27               sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
  91. 28         round(sum(f.maxbytes) / 1048576) max
  92. 29    from sys.v_$TEMP_SPACE_HEADER h,
  93. 30         sys.v_$Temp_extent_pool  p,
  94. 31         dba_temp_files           f
  95. 32  where p.file_id(+) = h.file_id
  96. 33     and p.tablespace_name(+) = h.tablespace_name
  97. 34     and f.file_id = h.file_id
  98. 35     and f.tablespace_name = h.tablespace_name
  99. 36  group by h.tablespace_name
  100. 37  ORDER BY 1
  101. 38  /

  102. TABLESPACE_NAME                MEGS_ALLOC  MEGS_FREE  MEGS_USED   PCT_FREE   PCT_USED        MAX
  103. ------------------------------ ---------- ---------- ---------- ---------- ---------- ----------
  104. EXAMPLE                               171          3        168          2         98      32768
  105. SYSAUX                                310         44        266         14         86      32768
  106. SYSTEM                               5700       2242       3458         39         61      32768
  107. TEMP                                 2968       2968          0        100          0      32768
  108. UNDOTBS1                             1165        825        340         71         29      32768
  109. USERS                                8985         36       8950          0        100      32768

  110. 6 rows selected.

  111. SQL> alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' resize 5000M;

  112. Database altered.

  113. SQL> REM tablespace report
  114. SQL>
  115. SQL> set linesize 200
  116. SQL>
  117. SQL> select a.tablespace_name,
  118.   2         round(a.bytes_alloc / 1024 / 1024) megs_alloc,
  119.   3         round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
  120.   4         round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
  121.   5         round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
  122.   6         100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
  123.   7         round(maxbytes / 1048576) Max
  124.   8    from (select f.tablespace_name,
  125.   9                 sum(f.bytes) bytes_alloc,
  126. 10                 sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
  127. 11            from dba_data_files f
  128. 12           group by tablespace_name) a,
  129. 13         (select f.tablespace_name, sum(f.bytes) bytes_free
  130. 14            from dba_free_space f
  131. 15           group by tablespace_name) b
  132. 16  where a.tablespace_name = b.tablespace_name(+)
  133. 17  union all
  134. 18  select h.tablespace_name,
  135. 19         round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
  136. 20         round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  137. 21               1048576) megs_free,
  138. 22         round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
  139. 23         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  140. 24               sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
  141. 25         100 -
  142. 26         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  143. 27               sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
  144. 28         round(sum(f.maxbytes) / 1048576) max
  145. 29    from sys.v_$TEMP_SPACE_HEADER h,
  146. 30         sys.v_$Temp_extent_pool  p,
  147. 31         dba_temp_files           f
  148. 32  where p.file_id(+) = h.file_id
  149. 33     and p.tablespace_name(+) = h.tablespace_name
  150. 34     and f.file_id = h.file_id
  151. 35     and f.tablespace_name = h.tablespace_name
  152. 36  group by h.tablespace_name
  153. 37  ORDER BY 1
  154. 38  /

  155. TABLESPACE_NAME                MEGS_ALLOC  MEGS_FREE  MEGS_USED   PCT_FREE   PCT_USED        MAX
  156. ------------------------------ ---------- ---------- ---------- ---------- ---------- ----------
  157. EXAMPLE                               171          3        168          2         98      32768
  158. SYSAUX                                310         44        266         14         86      32768
  159. SYSTEM                               5000       1542       3458         31         69      32768
  160. TEMP                                 2968       2968          0        100          0      32768
  161. UNDOTBS1                             1165        825        340         71         29      32768
  162. USERS                                8985         36       8950          0        100      32768

  163. 6 rows selected.

  164. SQL>  alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' resize 3460;
  165. alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' resize 3460
  166. *
  167. ERROR at line 1:
  168. ORA-03214: File Size specified is smaller than minimum required


  169. SQL>  alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' resize 3460M;
  170. alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' resize 3460M
  171. *
  172. ERROR at line 1:
  173. ORA-03297: file contains used data beyond requested RESIZE value


  174. SQL> alter database datafile '/s01/oradata/G10R21/datafile/o1_mf_system_7ch8004t_.dbf' resize 3470M;

  175. Database altered.

  176. SQL> REM tablespace report
  177. SQL>
  178. SQL> set linesize 200
  179. SQL>
  180. SQL> select a.tablespace_name,
  181.   2         round(a.bytes_alloc / 1024 / 1024) megs_alloc,
  182.   3         round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
  183.   4         round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
  184.   5         round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
  185.   6         100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
  186.   7         round(maxbytes / 1048576) Max
  187.   8    from (select f.tablespace_name,
  188.   9                 sum(f.bytes) bytes_alloc,
  189. 10                 sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
  190. 11            from dba_data_files f
  191. 12           group by tablespace_name) a,
  192. 13         (select f.tablespace_name, sum(f.bytes) bytes_free
  193. 14            from dba_free_space f
  194. 15           group by tablespace_name) b
  195. 16  where a.tablespace_name = b.tablespace_name(+)
  196. 17  union all
  197. 18  select h.tablespace_name,
  198. 19         round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
  199. 20         round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  200. 21               1048576) megs_free,
  201. 22         round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
  202. 23         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  203. 24               sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
  204. 25         100 -
  205. 26         round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
  206. 27               sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
  207. 28         round(sum(f.maxbytes) / 1048576) max
  208. 29    from sys.v_$TEMP_SPACE_HEADER h,
  209. 30         sys.v_$Temp_extent_pool  p,
  210. 31         dba_temp_files           f
  211. 32  where p.file_id(+) = h.file_id
  212. 33     and p.tablespace_name(+) = h.tablespace_name
  213. 34     and f.file_id = h.file_id
  214. 35     and f.tablespace_name = h.tablespace_name
  215. 36  group by h.tablespace_name
  216. 37  ORDER BY 1
  217. 38  /

  218. TABLESPACE_NAME                MEGS_ALLOC  MEGS_FREE  MEGS_USED   PCT_FREE   PCT_USED        MAX
  219. ------------------------------ ---------- ---------- ---------- ---------- ---------- ----------
  220. EXAMPLE                               171          3        168          2         98      32768
  221. SYSAUX                                310         44        266         14         86      32768
  222. SYSTEM                               3470         12       3458          0        100      32768
  223. TEMP                                 2968       2968          0        100          0      32768
  224. UNDOTBS1                             1165        825        340         71         29      32768
  225. USERS                                8985         36       8950          0        100      32768

  226. 6 rows selected.
复制代码

回复 只看该作者 道具 举报

6#
发表于 2011-12-8 20:34:23
您所说如果设置的值过小会导致ORA-03297: file contains used data beyond requested RESIZE value

导致这个错误的原因是因为resize的大小 小于hwm水位线的值就会报这个错误吗?

回复 只看该作者 道具 举报

7#
发表于 2011-12-8 23:54:33
实际上datafile 没有高水位high water mark一说 :there’s no HWM for datafiles, it’s just a virtual term to describe the last block containing data in the data file, which is the minimum size allowed for sizing down the data file.

你可以尝试换一个大小去resize , 把操作过程贴出来

回复 只看该作者 道具 举报

8#
发表于 2011-12-12 16:16:26
  1. SQL> ALTER DATABASE DATAFILE '/oradata/brjl/system01.dbf' RESIZE 7000M;
  2. ALTER DATABASE DATAFILE '/oradata/brjl/system01.dbf' RESIZE 7000M
  3. *
  4. ERROR at line 1:
  5. ORA-03297: file contains used data beyond requested RESIZE value


  6. SQL> ALTER DATABASE DATAFILE '/oradata/brjl/system01.dbf' RESIZE 7200m;
  7. ALTER DATABASE DATAFILE '/oradata/brjl/system01.dbf' RESIZE 7200m
  8. *
  9. ERROR at line 1:
  10. ORA-03297: file contains used data beyond requested RESIZE value
复制代码

回复 只看该作者 道具 举报

9#
发表于 2011-12-12 18:51:17
  1. set linesize 140 pagesize 1400
  2. col segment_name for a40
  3. select segment_name,segment_type,block_id from dba_extents where file_id=1 order by block_id desc ;
复制代码
查一下

回复 只看该作者 道具 举报

10#
发表于 2011-12-12 21:27:17

回复 9# 的帖子

我第一个帖子里查过max的block_id是7362,我知道现在是只能resize到7362附近,但是实际只使用了300多m,我是想能大幅度缩小system表空间的大小,但是我又不太敢随便shrink或者做别的操作,现在有办法回缩表空间大小吗还?

select max(block_id)*8/1024 "m size" from dba_extents where tablespace_name='SYSTEM'

7362.0703125

回复 只看该作者 道具 举报

11#
发表于 2011-12-12 21:33:06

回复 10# 的帖子

查一下 该Extent属于哪个对象?  因该不是system表空间原有的段

[ 本帖最后由 maclean 于 2011-12-12 21:39 编辑 ]

回复 只看该作者 道具 举报

12#
发表于 2011-12-13 11:26:17
  1. SQL> select SEGMENT_NAME,SEGMENT_TYPE,BLOCK_ID from dba_extents where tablespace_name='SYSTEM' ORDER BY BLOCK_ID DESC;

  2. SEGMENT_NAME SEGMENT_TYPE BLOCK_ID
  3. -------------------------------------------------------------------------------- ------------------ ----------
  4. C_OBJ#_INTCOL# CLUSTER 942345
  5. HIST_HEAD$ TABLE 942217
  6. C_OBJ#_INTCOL# CLUSTER 868361
  7. I_H_OBJ#_COL# INDEX 868233
  8. SUMPARTLOG$ TABLE 84281
  9. I_OBJ#_INTCOL# INDEX 84273
  10. I_OBJ1 INDEX 84265
  11. C_COBJ# CLUSTER 84257
  12. C_TS# CLUSTER 84249
  13. TABPART$ TABLE 84241
  14. I_MON_MODS$_OBJ INDEX 84233
  15. C_OBJ#_INTCOL# CLUSTER 84105
  16. C_OBJ#_INTCOL# CLUSTER 83977
  17. SOURCE$ TABLE 42505
  18. IDL_UB2$ TABLE 42377
  19. C_FILE#_BLOCK# CLUSTER 42249
  20. FGA_LOG$ TABLE 42121
  21. FGA_LOG$ TABLE 41993
  22. FGA_LOG$ TABLE 41865
复制代码

回复 只看该作者 道具 举报

13#
发表于 2011-12-13 21:56:24
How to Resize a Datafile


Applies to:  Oracle Server - Enterprise Edition - Version: 7.3.0.0 and later   [Release: 7.3.0 and later ]
Information in this document applies to any platform.
PurposeThis note will discuss resizing of Oracle datafiles (larger or smaller)
Scope and ApplicationThe intended audience for this document is for experienced DBA's  
How to Resize a DatafileOracle file sizing is vital part of managing Oracle databases

In older versions (Oracle 7.1 and lower) the only methods available to resize tablespace storage were

    * Drop and recreate the tablespace with different sized datafiles (decrease / shrink)
    * Add one or more datafiles to the tablespace (increase)

Beginning in Oracle 7.2 Oracle introduced the ALTER DATABASE DATAFILE .... RESIZE command.

This option allows you to change the physical size of a datafile from what was specified during its creation.

  Attempting to use the RESIZE command on versions prior to 7.2 will receive the following error:

ORA-00923: FROM keyword not found where expected

  =============================
1. Increase Datafile Size
=============================To increase the size of a datafile, you would use the command:

  ALTER DATABASE DATAFILE '<full path and name of the file>' RESIZE [K|M|G];

where the size specified is larger than the existing file size.

The current size of a datafile may be found by querying V$DATAFILE.BYTES or DBA_DATA_FILES.BYTES

Examples:

  column file_name format a45

select file_name, bytes from dba_data_files where file_name like '%test%';

FILE_NAME                                     BYTES
--------------------------------------------- ----------
/u01/app/oracle/oradata/v10205/test.dbf          1048576


ALTER DATABASE DATAFILE '/u01/app/oracle/oradata/v10205/test.dbf' RESIZE 10567680;

    In this example the size before resize was 1048576 bytes and after the resize 10567680 bytes

  SELECT FILE#, STATUS, ENABLED, CHECKPOINT_CHANGE#, BYTES, CREATE_BYTES, NAME FROM V$DATAFILE;

FILE#  STATUS  ENABLED    CHECKPOINT BYTES      CREATE_BYT NAME
------ ------- ---------- ---------- ---------- ---------- ----------------
5      ONLINE  READ WRITE 7450       2097152    102400     /databases/oracle/test.dbf


   In this example the file was created with a size of 100K (CREATE_BYTES) and is currently 2 MB in size ... this shows that the file was resized.

  =============================
2. Decrease Datafile Size
=============================
To decrease the size of a datafile, you would use the command:

  ALTER DATABASE DATAFILE '<full path and name of the file>' RESIZE [K|M|G];

where the size specified is smaller than the existing file size.

The current size of a datafile may be found by querying V$DATAFILE.BYTES or DBA_DATA_FILES.BYTES (see section 1 for examples)

Reducing the size of a datafile is more complicated than increasing the size of a datafile as space cannot be deallocated from a datafile that is currently being used by database objects.

To remove space from a datafile, you have to have contiguous free space at the END of the datafile.  

The view DBA_FREE_SPACE is used to display the free space (space not being used) in a datafile.

For example:

  SELECT * FROM DBA_FREE_SPACE
WHERE TABLESPACE_NAME='TEST'
ORDER BY BLOCK_ID;

TABLESPACE_NAME    FILE_ID    BLOCK_ID   BYTES      BLOCKS
------------------ ---------- ---------- ---------- ----------
TEST                        5          2     102400         50
TEST                        5         55      96256         47
TEST                        5        102    1890304        923

There are two large extents at the high end of the datafile
  
  • BLOCK_ID=55 contains 47 blocks
  • BLOCK_ID=102 contains 923 blocks
This means there are 1986560 unused bytes at the end of our datafile, almost 2 MB.

We want to leave some room for growth in our datafile, and depending on how the objects in that datafile allocate new extents, we could remove up to 1.89 MB of disk space from the datafile without damaging any objects in the tablespace.

If you have a large extent in the middle of a datafile, and some object taking up room at the end of the datafile, you can use the query FINDEXT.SQL below to find this object. If you export this object, then drop it, you should then free up contiguous space at the end of your datafile so you will be able to resize it smaller.

Make sure you leave enough room in the datafile for importing the object back into the tablespace.

  =============================
3. Cautions and Warnings and Notes
=============================
A) For safety reasons, you should take a backup of your database whenever you change its structure, which includes altering the size of datafiles.

B) If you try to resize a datafile to a size smaller than is needed to contain all the database objects in that datafile, the following error is returned:

ORA-03297: file contains blocks of data beyond requested RESIZE value

Or

ORA-03297: file contains used data beyond requested RESIZE value

The resize operation will fail at this point.

C) If you try to resize a datafile larger than can be created, you will also get an error.

For instance, if trying to create a file of 2 GB, without having 2 GB of available disk space the following errors will be returned:

ORA-01237: cannot extend datafile
ORA-01110: data file : ''
ORA-19502: write error on file "", blockno (blocksize=)
ORA-27072: File I/O error

If you check V$DATAFILE, you will see that the file size does not change unless the operation is successful.

D) MANUAL versus AUTOMATIC extension:

Be careful giving datafiles the AUTOEXTEND attribute, and make sure to specify the NEXT and MAXSIZE parameters.

If using dictionary managed tablespaces (DMT)
  
  • set appropriate values for the default storage parameters on tablespace level and the MAXEXTENTS parameter
  • avoid UNLIMITED sizes and extents to prevent objects with a very high number of extents to be created which causes not only a huge number of records in the dictionary tables, but dropping them can tade long time with SMON consuming a lot of CPU resources
If using multiple database writers (db_writers > 1) in RDBMS versions below version 7.3.4.1, might be encounterd. This appears as ORA-7374 errors when accessing the datafile after it has been resized.  The workaround is to shutdown and restart the database after resizing a datafile (a convenient time to take a backup). This will cause the new datafile size information to be refreshed to all the DBWR slave processes.

E) Please be aware that beside the command 'ALTER DATABASE DATAFILE ... RESIZE ... ' there are still alternatives like the export and import utility (including DataPump) to perform a resize of a datafile. Using export/import will lead also result in a reorganization of the objects in the tablespace related to the datafile.
  =============================
4. SCRIPTS
=============================
  FINDEXT.SQL  
  -- FINDEXT.SQL

-- This script lists all the extents contained in that datafile,
-- the block_id where the extent starts,
-- and how many blocks the extent contains.
-- It also shows the owner, segment name, and segment type.

-- Input: FILE_ID from DBA_DATA_FILES or FILE# from V$DATAFILE

SET ECHO OFF
SET PAGESIZ 25

column file_name format a50
select file_name, file_id from dba_data_files order by 2;

ttitle -
center 'Segment Extent Summary' skip 2

col ownr format a8 heading 'Owner' justify c
col type format a8 heading 'Type' justify c trunc
col name format a30 heading 'Segment Name' justify c
col exid format 990 heading 'Extent#' justify c
col fiid format 9990 heading 'File#' justify c
col blid format 99990 heading 'Block#' justify c
col blks format 999,990 heading 'Blocks' justify c

select owner ownr, segment_name name, segment_type type, extent_id exid, file_id fiid, block_id blid, blocks blks
from dba_extents
where file_id = &file_id
order by block_id
/

Sample Output:

  SQL> @findext.sql

FILE_NAME FILE_ID
-------------------------------------------------- ----------
/u01/app/oracle/oradata/v10205/system01.dbf 1
/u01/app/oracle/oradata/v10205/undotbs01.dbf 2
/u01/app/oracle/oradata/v10205/sysaux01.dbf 3
/u01/app/oracle/oradata/v10205/users01.dbf 4

Enter value for file_id: 4
old 3: where file_id = &file_id
new 3: where file_id = 4

Segment Extent Summary

Owner    Segment Name                   Type     Extent# File# Block# Blocks
-------- ------------------------------ -------- ------- ----- ------ --------
USER     EMP                            TABLE          0     4      2        5
USER     TAB3                           TABLE          0     4    108        5
USER     TEST                           TABLE          0     4    348        5
USER     PK_EMP                         INDEX          0     4    483        5
USER     EMP                            TABLE          1     4    433        5
USER     EMP                            TABLE          2     4    438       10
USER     PK_EMP                         INDEX          1     4    488       10
  
  SHRINK_DATAFILE.SQL

  -- SHRINK_DATAFILE.SQL

-- This script lists the object names and types that must be moved in order to resize a datafile to a specified smaller size

-- Input: FILE_ID from DBA_DATA_FILES or FILE# from V$DATAFILE
-- Size in bytes that the datafile will be resized to

SET SERVEROUTPUT ON

DECLARE
     V_FILE_ID NUMBER;
     V_BLOCK_SIZE NUMBER;
     V_RESIZE_SIZE NUMBER;
BEGIN
     V_FILE_ID := &FILE_ID;
     V_RESIZE_SIZE := &RESIZE_FILE_TO;

     SELECT BLOCK_SIZE INTO V_BLOCK_SIZE FROM V$DATAFILE WHERE FILE# = V_FILE_ID;

     DBMS_OUTPUT.PUT_LINE('.');
     DBMS_OUTPUT.PUT_LINE('.');
     DBMS_OUTPUT.PUT_LINE('.');
     DBMS_OUTPUT.PUT_LINE('OBJECTS IN FILE '||V_FILE_ID||' THAT MUST MOVE IN ORDER TO RESIZE THE FILE TO '||V_RESIZE_SIZE||' BYTES');
     DBMS_OUTPUT.PUT_LINE('===================================================================');
     DBMS_OUTPUT.PUT_LINE('NON-PARTITIONED OBJECTS');
     DBMS_OUTPUT.PUT_LINE('===================================================================');

     for my_record in (
          SELECT DISTINCT(OWNER||'.'||SEGMENT_NAME||' - OBJECT TYPE = '||SEGMENT_TYPE) ONAME
          FROM DBA_EXTENTS
          WHERE (block_id + blocks-1)*V_BLOCK_SIZE > V_RESIZE_SIZE
          AND FILE_ID = V_FILE_ID
          AND SEGMENT_TYPE NOT LIKE '%PARTITION%'
          ORDER BY 1) LOOP
               DBMS_OUTPUT.PUT_LINE(my_record.ONAME);
     END LOOP;

     DBMS_OUTPUT.PUT_LINE('===================================================================');
     DBMS_OUTPUT.PUT_LINE('PARTITIONED OBJECTS');
     DBMS_OUTPUT.PUT_LINE('===================================================================');

     for my_record in (
          SELECT DISTINCT(OWNER||'.'||SEGMENT_NAME||' - PARTITION = '||PARTITION_NAME||' - OBJECT TYPE = '||SEGMENT_TYPE) ONAME
          FROM DBA_EXTENTS
          WHERE (block_id + blocks-1)*V_BLOCK_SIZE > V_RESIZE_SIZE
          AND FILE_ID = V_FILE_ID
          AND SEGMENT_TYPE LIKE '%PARTITION%'
          ORDER BY 1) LOOP
               DBMS_OUTPUT.PUT_LINE(my_record.ONAME);
     END LOOP;

END;
/


Sample Output:

  SQL > @SHRINK_DATAFILE.SQL

Enter value for file_id: 2
old 6: V_FILE_ID := &FILE_ID;
new 6: V_FILE_ID := 2;
Enter value for resize_file_to: 300000000
old 7: V_RESIZE_SIZE := &RESIZE_FILE_TO;
new 7: V_RESIZE_SIZE := 300000000;
.
.
.
OBJECTS IN FILE 2 THAT MUST MOVE IN ORDER TO RESIZE THE FILE TO 300000000 BYTES
===================================================================
NON-PARTITIONED OBJECTS
===================================================================
SYS.I_WRI$_OPTSTAT_HH_OBJ_ICOL_ST - OBJECT TYPE = INDEX
...

===================================================================
PARTITIONED OBJECTS
===================================================================
SYS.WRH$_ACTIVE_SESSION_HISTORY - PARTITION = WRH$_ACTIVE_512113771_430 - OBJECT TYPE = TABLE PARTITION
...
    =============================
5. CASE STUDY
=============================sqlplus / as sysdba

    -- Setup for the testcase
alter system set recyclebin=on;

create tablespace test datafile '/u01/app/oracle/oradata/v10205/test.dbf' size 100m extent management local uniform size 1m;

select bytes from v$datafile where file# = 5;

    BYTES
----------
104857600


!ls -alt /u01/app/oracle/oradata/v10205/test.dbf

    -rw-r----- 1 oracle dba 104865792 Apr 20 07:49 /u01/app/oracle/oradata/v10205/test.dbf

create user test identified by test;
grant dba to test;
alter user test default tablespace test;
connect test/test;
    -- Fill up the TEST Tablespace
BEGIN
   for i in 1..19 LOOP
      execute immediate 'create table ' || 'TEST'||i ||' as select * from dba_objects';
   end loop;
end;
/

select bytes-ebytes from (select sum(bytes) ebytes from dba_extents where file_id=5), dba_data_files where file_id=5;

    BYTES-EBYTES
------------
5242880

select sum(bytes) from dba_free_space where file_id=5;

    SUM(BYTES)
----------
4194304
    -- Examine the extent storage for the TEST datafile with FINDEXT.SQL
@FINDEXT

                                      Segment Extent Summary

FILE_NAME                                             FILE_ID
-------------------------------------------------- ----------
/u01/app/oracle/oradata/v10205/system01.dbf                 1
/u01/app/oracle/oradata/v10205/undotbs01.dbf                2
/u01/app/oracle/oradata/v10205/sysaux01.dbf                 3
/u01/app/oracle/oradata/v10205/users01.dbf                  4
/u01/app/oracle/oradata/v10205/test.dbf                     5

Enter value for file_id: 5
old   3: where file_id = &file_id
new   3: where file_id = 5

                             Segment Extent Summary

Owner            Segment Name            Type   Extent# File# Block#  Blocks
-------- ------------------------------ -------- ------- ----- ------ --------
TEST     TEST1                          TABLE          0     5      9      128
TEST     TEST1                          TABLE          1     5    137      128
TEST     TEST1                          TABLE          2     5    265      128
TEST     TEST1                          TABLE          3     5    393      128
TEST     TEST1                          TABLE          4     5    521      128
TEST     TEST2                          TABLE          0     5    649      128
...
TEST     TEST18                         TABLE          3     5  11273      128
TEST     TEST18                         TABLE          4     5  11401      128
TEST     TEST19                         TABLE          0     5  11529      128
TEST     TEST19                         TABLE          1     5  11657      128
TEST     TEST19                         TABLE          2     5  11785      128
TEST     TEST19                         TABLE          3     5  11913      128
TEST     TEST19                         TABLE          4     5  12041      128   

-- DROP TABLES TEST2 TO TEST17 AND TEST19

BEGIN
   for i in 2..17 LOOP
      execute immediate 'DROP table ' || 'TEST'||i;
   end loop;
   execute immediate 'DROP TABLE TEST19';
end;
/
    -- Examine the storage for the TEST datafile with FINDEXT.SQL
@FINDEXT

                                       Segment Extent Summary

FILE_NAME                                             FILE_ID
-------------------------------------------------- ----------
/u01/app/oracle/oradata/v10205/system01.dbf                 1
/u01/app/oracle/oradata/v10205/undotbs01.dbf                2
/u01/app/oracle/oradata/v10205/sysaux01.dbf                 3
/u01/app/oracle/oradata/v10205/users01.dbf                  4
/u01/app/oracle/oradata/v10205/test.dbf                     5

Enter value for file_id: 5
old   3: where file_id = &file_id
new   3: where file_id = 5

                             Segment Extent Summary

Owner            Segment Name            Type   Extent# File# Block#  Blocks
-------- ------------------------------ -------- ------- ----- ------ --------
TEST     TEST1                          TABLE          0     5      9      128
TEST     TEST1                          TABLE          1     5    137      128
TEST     TEST1                          TABLE          2     5    265      128
TEST     TEST1                          TABLE          3     5    393      128
TEST     TEST1                          TABLE          4     5    521      128
TEST     TEST18                         TABLE          0     5  10889      128
TEST     TEST18                         TABLE          1     5  11017      128
TEST     TEST18                         TABLE          2     5  11145      128
TEST     TEST18                         TABLE          3     5  11273      128
TEST     TEST18                         TABLE          4     5  11401      128   

-- NOTE THAT THERE IS NOW A LARGE HOLE IN THE MIDDLE OF THE TEST TABLESPACE DATAFILE
    -- Examine the Recylebin Contents for the Test Tablespace
SELECT ORIGINAL_NAME FROM DBA_RECYCLEBIN WHERE TS_NAME = 'TEST';

    ORIGINAL_NAME
--------------------------------
TEST2
TEST3
TEST4
TEST5
TEST6
TEST7
TEST8
TEST9
TEST10
TEST11
TEST12
TEST13
TEST14
TEST15
TEST16
TEST17
TEST19

    -- Determine the the amount of data remaining in active extents in the TEST tablespace datafile
SELECT SUM(BYTES) FROM DBA_EXTENTS WHERE FILE_ID = 5;

SUM(BYTES)
----------
10485760

-- Remember .. when resizing datafiles smaller .. extra space should be allowed for future growth as well as space for the datafile headers
--      this test was run with an overhead of 10 (8K) blocks
    -- Determine what objects must be moved in order for the resize to succeed
@SHRINK_DATAFILE.SQL

    Enter value for file_id: 5
old 6: V_FILE_ID := &FILE_ID;
new 6: V_FILE_ID := 5;
Enter value for resize_file_to: 10567680
old 7: V_RESIZE_SIZE := &RESIZE_FILE_TO;
new 7: V_RESIZE_SIZE := 10567680;
.
.
.
Objects in File 5 that must move in order to resize the file to 10567680 BYTES
=================================================
TEST.TEST18 - OBJECT TYPE = TABLE

-- Show that the resize will not succeed with the objects in their present position

ALTER DATABASE DATAFILE '/u01/app/oracle/oradata/v10205/test.dbf' RESIZE 10567680;

ALTER DATABASE DATAFILE '/u01/app/oracle/oradata/v10205/test.dbf' RESIZE 10567680
*
ERROR at line 1:
ORA-03297: file contains used data beyond requested RESIZE value

-- Move the TEST18 table to another tablespace so that the resize can succeed

ALTER TABLE TEST18 MOVE TABLESPACE USERS;

-- Attempt to resize the table again

ALTER DATABASE DATAFILE '/u01/app/oracle/oradata/v10205/test.dbf' RESIZE 10567680;

ALTER DATABASE DATAFILE '/u01/app/oracle/oradata/v10205/test.dbf' RESIZE 10567680
*
ERROR at line 1:
ORA-03297: file contains used data beyond requested RESIZE value

-- The reason that this resize failed is there are still objects in the recycle bin ... they need to removed before the resize can succeed

purge tablespace test;

-- Tablespace purged.

-- Attempt the resize again

ALTER DATABASE DATAFILE '/u01/app/oracle/oradata/v10205/test.dbf' RESIZE 10567680;

-- Database altered.

select bytes from v$datafile where file# = 5;

    BYTES
----------
10567680

!ls -alt /u01/app/oracle/oradata/v10205/test.dbf

    -rw-r----- 1 oracle dba 10575872 Apr 20 06:19 /u01/app/oracle/oradata/v10205/test.dbf



-- Return the TEST18 table to the TEST tablespace

ALTER TABLE TEST18 MOVE TABLESPACE TEST;


-- CLEAN UP

CONNECT / AS SYSDBA
drop user test cascade;
drop tablespace test including contents and datafiles cascade constraints;

回复 只看该作者 道具 举报

14#
发表于 2011-12-13 21:58:02
To decrease the size of a datafile, you would use the command:

  ALTER DATABASE DATAFILE '<full path and name of the file>' RESIZE [K|M|G];

where the size specified is smaller than the existing file size.

The current size of a datafile may be found by querying V$DATAFILE.BYTES or DBA_DATA_FILES.BYTES (see section 1 for examples)

Reducing the size of a datafile is more complicated than increasing the size of a datafile as space cannot be deallocated from a datafile that is currently being used by database objects.

To remove space from a datafile, you have to have contiguous free space at the END of the datafile.  

The view DBA_FREE_SPACE is used to display the free space (space not being used) in a datafile.

For example:

  SELECT * FROM DBA_FREE_SPACE
WHERE TABLESPACE_NAME='TEST'
ORDER BY BLOCK_ID;

TABLESPACE_NAME    FILE_ID    BLOCK_ID   BYTES      BLOCKS
------------------ ---------- ---------- ---------- ----------
TEST                        5          2     102400         50
TEST                        5         55      96256         47
TEST                        5        102    1890304        923

There are two large extents at the high end of the datafile
  

    BLOCK_ID=55 contains 47 blocks
    BLOCK_ID=102 contains 923 blocks

This means there are 1986560 unused bytes at the end of our datafile, almost 2 MB.

We want to leave some room for growth in our datafile, and depending on how the objects in that datafile allocate new extents, we could remove up to 1.89 MB of disk space from the datafile without damaging any objects in the tablespace.

If you have a large extent in the middle of a datafile, and some object taking up room at the end of the datafile, you can use the query FINDEXT.SQL below to find this object. If you export this object, then drop it, you should then free up contiguous space at the end of your datafile so you will be able to resize it smaller.

Make sure you leave enough room in the datafile for importing the object back into the tablespace.

回复 只看该作者 道具 举报

15#
发表于 2011-12-13 22:01:12
因为system 数据文件的 尾部 仍有被使用的Extent 这导致resize 操作无法成功;

而这些Extent 是属于一些 bootstrap 重要的自举对象的,所以我们无法轻易去移动他们:

SQL> select SEGMENT_NAME,SEGMENT_TYPE,BLOCK_ID from dba_extents where tablespace_name='SYSTEM' ORDER BY BLOCK_ID DESC;

SEGMENT_NAME SEGMENT_TYPE BLOCK_ID
-------------------------------------------------------------------------------- ------------------ ----------
C_OBJ#_INTCOL# CLUSTER 942345
HIST_HEAD$ TABLE 942217
C_OBJ#_INTCOL# CLUSTER 868361
I_H_OBJ#_COL# INDEX 868233
SUMPARTLOG$ TABLE 84281
I_OBJ#_INTCOL# INDEX 84273
I_OBJ1 INDEX 84265
C_COBJ# CLUSTER 84257
C_TS# CLUSTER 84249
TABPART$ TABLE 84241


究其原因是 之前 有大的数据段存放在system表空间上,之后这些大的数据段被清理掉,导致出现 该数据文件头和尾仍被占用,而 中间出现大的Free Extents,从用户角度看就是有大量的空闲空间,但是却无法回收,resize 失败,出现ORA-03297: file contains used data beyond requested RESIZE value错误

回复 只看该作者 道具 举报

16#
发表于 2011-12-13 22:03:42
  1. How to Resolve ORA-03297 When Resizing a Datafile by Finding the Table Highwatermark

  2. Applies to:
  3. Oracle Server - Enterprise Edition - Version: 8.1.5.0 and later   [Release: 8.1.5 and later ]
  4. Information in this document applies to any platform.
  5. Goal
  6. In a number of cases it is desired to shrink an oversized datafile. The challenge is then up to find to which size the datafile can be shrunk? Using the trial and error approach will likely give:

  7. SQL> alter database datafile '/oradata/v112/users01.dbf' resize 117248K;
  8. alter database datafile '/oradata/v112/users01.dbf' resize 117248K
  9. *
  10. ERROR at line 1:
  11. ORA-03297: file contains used data beyond requested RESIZE value

  12. The error is due to fact that there are allocated extents between the size to resize/shrink to and the end-of-file (might be space management blocks, so not necessary belonging to a segment).
  13. Solution

  14. Two options do exist to find the highwater mark of a datafile:

  15. - checking backwards for free space at end of file (proven to be the fastest)

  16. - check highest allocated extent in datafile (it might be that space management blocks are above last allocated extend)

  17. 1) checking backwards for free space at end of file

  18. Due to added functionality (different blocksizes for tablespaces) the script has been split into:

  19. - Oracle version 9 and higher

  20. - Oracle version 8 and lower
  21. REM Script is meant for Oracle version 9 and higher
  22. REM -----------------------------------------------

  23. set serveroutput on
  24. exec dbms_output.enable(1000000);

  25. declare

  26. cursor c_dbfile is
  27. select f.tablespace_name,f.file_name,f.file_id,f.blocks,t.block_size
  28. ,decode(t.allocation_type,'UNIFORM',t.initial_extent/t.block_size,0) uni_extent
  29. ,decode(t.allocation_type,'UNIFORM',(128+(t.initial_extent/t.block_size)),128) file_min_size
  30. from dba_data_files f,
  31. dba_tablespaces t
  32. where f.tablespace_name = t.tablespace_name
  33. and t.status = 'ONLINE'
  34. order by f.tablespace_name,f.file_id;

  35. cursor c_freespace(v_file_id in number) is
  36. select block_id, block_id+blocks max_block
  37. from dba_free_space
  38. where file_id = v_file_id
  39. order by block_id desc;

  40. /* variables to check settings/values */
  41. dummy number;
  42. checkval varchar2(10);
  43. block_correction number;

  44. /* running variable to show (possible) end-of-file */
  45. file_min_block number;

  46. /* variables to check if recycle_bin is on and if extent as checked is in ... */
  47. recycle_bin boolean:=false;
  48. extent_in_recycle_bin boolean;

  49. /* exception handler needed for non-existing tables note:344940.1 */
  50. sqlstr varchar2(100);
  51. table_does_not_exist exception;
  52. pragma exception_init(table_does_not_exist,-942);

  53. /* variable to spot space wastage in datafile of uniform tablespace */
  54. space_wastage number;

  55. begin

  56. /* recyclebin is present in Oracle 10.2 and higher and might contain extent as checked */
  57. begin
  58. select value into checkval from v$parameter where name = 'recyclebin';
  59. if checkval = 'on'
  60. then
  61. recycle_bin := true;
  62. end if;
  63. exception
  64. when no_data_found
  65. then
  66. recycle_bin := false;
  67. end;

  68. /* main loop */
  69. for c_file in c_dbfile
  70. loop
  71. /* initialization of loop variables */
  72. dummy :=0;
  73. extent_in_recycle_bin := false;
  74. file_min_block := c_file.blocks;

  75. begin

  76. space_wastage:=0; /* reset for every file check */

  77. <<check_free>>

  78. for c_free in c_freespace(c_file.file_id)
  79. loop
  80. /* if blocks is an uneven value there is a need to correct
  81. with -1 to compare with end-of-file which is even */
  82. block_correction := (0-mod(c_free.max_block,2));
  83. if file_min_block = c_free.max_block+block_correction
  84. then

  85. /* free extent is at end so file can be resized */
  86. file_min_block := c_free.block_id;

  87. /* Uniform sized tablespace check if space at end of file
  88. is less then uniform extent size */
  89. elsif (c_file.uni_extent !=0) and ((c_file.blocks - c_free.max_block) < c_file.uni_extent)
  90. then

  91. /* uniform tablespace which has a wastage of space in datafile
  92. due to fact that space at end of file is smaller than uniform extent size */

  93. space_wastage:=c_file.blocks - c_free.max_block;
  94. file_min_block := c_free.block_id;

  95. else
  96. /* no more free extent at end of file, file cannot be further resized */
  97. exit check_free;
  98. end if;
  99. end loop;
  100. end;

  101. /* check if file can be resized, minimal size of file 128 {+ initial_extent} blocks */
  102. if (file_min_block = c_file.blocks) or (c_file.blocks <= c_file.file_min_size)
  103. then

  104. dbms_output.put_line('Tablespace: '||c_file.tablespace_name||' Datafile: '||c_file.file_name);
  105. dbms_output.put_line('cannot be resized no free extents found');
  106. dbms_output.put_line('.');

  107. else

  108. /* file needs minimal no of blocks which does vary over versions,
  109. using safe value of 128 {+ initial_extent} */
  110. if file_min_block < c_file.file_min_size
  111. then
  112. file_min_block := c_file.file_min_size;
  113. end if;


  114. dbms_output.put_line('Tablespace: '||c_file.tablespace_name||' Datafile: '||c_file.file_name);
  115. dbms_output.put_line('current size: '||(c_file.blocks*c_file.block_size)/1024||'K'||' can be resized to: '||round((file_min_block*c_file.block_size)/1024)||'K (reduction of: '||round(((c_file.blocks-file_min_block)/c_file.blocks)*100,2)||' %)');


  116. /* below is only true if recyclebin is on */
  117. if recycle_bin
  118. then
  119. begin
  120. sqlstr:='select distinct 1 from recyclebin$ where file#='||c_file.file_id;
  121. execute immediate sqlstr into dummy;

  122. if dummy > 0
  123. then

  124. dbms_output.put_line('Extents found in recyclebin for above file/tablespace');
  125. dbms_output.put_line('Implying that purge of recyclebin might be needed in order to resize');
  126. dbms_output.put_line('SQL> purge tablespace '||c_file.tablespace_name||';');
  127. end if;
  128. exception
  129. when no_data_found
  130. then null;
  131. when table_does_not_exist
  132. then null;
  133. end;
  134. end if;
  135. dbms_output.put_line('SQL> alter database datafile '''||c_file.file_name||''' resize '||round((file_min_block*c_file.block_size)/1024)||'K;');

  136. if space_wastage!=0
  137. then
  138. dbms_output.put_line('Datafile belongs to uniform sized tablespace and is not optimally sized.');
  139. dbms_output.put_line('Size of datafile is not a multiple of NN*uniform_extent_size + overhead');
  140. dbms_output.put_line('Space that cannot be used (space wastage): '||round((space_wastage*c_file.block_size)/1024)||'K');
  141. dbms_output.put_line('For optimal usage of space in file either resize OR increase to: '||round(((c_file.blocks+(c_file.uni_extent-space_wastage))*c_file.block_size)/1024)||'K');
  142. end if;

  143. dbms_output.put_line('.');

  144. end if;

  145. end loop;

  146. end;
  147. /

  148. *) The absolute minimum size of a datafile varies per version/tablespace type.
  149.      In above case 128*8K (=1Mb) is used, but this might be too low.

  150. Example output for Oracle version 9 and higher:
  151. Tablespace: TEST Datafile: +DG1/test01.dbf
  152. current size: 11264K can be resized to: 4096K (reduction of: 63.64 %)
  153. Extents found in recyclebin for above file/tablespace
  154. Implying that purge of recyclebin might be needed in order to resize
  155. SQL> purge tablespace TEST;
  156. SQL> alter database datafile '+DG1/test01.dbf' resize 4096K;
  157. Datafile belongs to uniform sized tablespace and is not optimally sized.
  158. Size of datafile is not a multiple of NN*uniform_extent_size + overhead
  159. Space that cannot be used (space wastage): 1024K
  160. For optimal usage of space in file either resize OR increase to: 13312K
  161. .
  162. Tablespace: TEST Datafile: +DG2/test02.dbf
  163. current size: 10240K can be resized to: 4096K (reduction of: 60 %)
  164. SQL> alter database datafile '+DG2/test02.dbf' resize 4096K;
  165. .
  166. Tablespace: UNDOTBS1 Datafile: /oradata/v1122/undotbs01.dbf
  167. current size: 660480K can be resized to: 103424K (reduction of: 84.34 %)
  168. SQL> alter database datafile '/oradata/v1122/undotbs01.dbf' resize 103424K;
  169. .
  170. Tablespace: USERS Datafile: /oradata/v1122/users01.dbf
  171. cannot be resized no free extents found


  172. REM Script is meant for Oracle version 8 and lower
  173. REM ----------------------------------------------

  174. set serveroutput on
  175. exec dbms_output.enable(1000000);

  176. declare

  177. cursor c_dbfile is
  178. select f.tablespace_name,f.file_name,f.file_id,f.blocks
  179. from dba_data_files f,
  180. dba_tablespaces t
  181. where f.tablespace_name = t.tablespace_name
  182. and t.status = 'ONLINE'
  183. order by f.tablespace_name,f.file_id;

  184. cursor c_freespace(v_file_id in number) is
  185. select block_id, block_id+blocks max_block
  186. from dba_free_space
  187. where file_id = v_file_id
  188. order by block_id desc;

  189. /* variables to check settings/values */
  190. block_correction number;
  191. block_size number;

  192. /* running variable to show (possible) end-of-file */
  193. file_min_block number;

  194. begin

  195. select value into block_size from v$parameter where name='db_block_size';

  196. /* main loop */
  197. for c_file in c_dbfile
  198. loop
  199. /* initialization of loop variables */
  200. file_min_block := c_file.blocks;

  201. begin

  202. <<check_free

  203. for c_free in c_freespace(c_file.file_id)
  204. loop
  205. /* if blocks is an uneven value there is a need to correct with -1 to compare with end-of-file which is even */
  206. block_correction := (0-mod(c_free.max_block,2));
  207. if file_min_block = c_free.max_block+block_correction
  208. then

  209. /* free extent is at end so file can be resized */
  210. file_min_block := c_free.block_id;

  211. else
  212. /* no more free extent at end of file, file cannot be further resized */
  213. exit check_free;
  214. end if;
  215. end loop;
  216. end;

  217. /* check if file can be resized, minimal size of file 16 blocks */
  218. if (file_min_block = c_file.blocks) or (c_file.blocks <= 16)
  219. then

  220. dbms_output.put_line('Tablespace: '||c_file.tablespace_name||' Datafile: '||c_file.file_name);
  221. dbms_output.put_line('cannot be resized no free extents found');
  222. dbms_output.put_line('.');

  223. else

  224. /* file needs minimal no of blocks which does vary over versions */
  225. if file_min_block < 16
  226. then
  227. file_min_block := 16;
  228. end if;

  229. dbms_output.put_line('Tablespace: '||c_file.tablespace_name||' Datafile: '||c_file.file_name);
  230. dbms_output.put_line('current size: '||(c_file.blocks*block_size)/1024||'K'||' can be resized to: '||round((file_min_block*block_size)/1024)||'K (reduction of: '||round(((c_file.blocks-file_min_block)/c_file.blocks)*100,2)||' %)');
  231. dbms_output.put_line('SQL> alter database datafile '''||c_file.file_name||''' resize '||round((file_min_block*block_size)/1024)||'K;');
  232. dbms_output.put_line('.');

  233. end if;

  234. end loop;

  235. end;
  236. /

  237. Example output for Oracle version 8 and lower:
  238. Tablespace: SYSTEM Datafile:
  239. /refresh/64bit/app/oracle/oradata/REF817U6/system01.dbf
  240. cannot be resized no free extents found
  241. .
  242. Tablespace: TEMP Datafile: /refresh/64bit/app/oracle/oradata/REF817U6/temp01.dbf
  243. current size: 69632K can be resized to: 128K (reduction of: 99.82 %)
  244. SQL> alter database datafile
  245. '/refresh/64bit/app/oracle/oradata/REF817U6/temp01.dbf' resize 128K;


  246. 2. Check highest allocated extent in datafile (likely slow when having many extents)
  247. column file_name format a50;
  248. column tablespace_name format a15;
  249. column highwater format 9999999999;
  250. set pagesize 9999

  251. select a.tablespace_name
  252. ,a.file_name
  253. ,(b.maximum+c.blocks-1)*d.db_block_size highwater
  254. from dba_data_files a
  255. ,(select file_id,max(block_id) maximum
  256. from dba_extents
  257. group by file_id) b
  258. ,dba_extents c
  259. ,(select value db_block_size
  260. from v$parameter
  261. where name='db_block_size') d
  262. where a.file_id = b.file_id
  263. and c.file_id = b.file_id
  264. and c.block_id = b.maximum
  265. order by a.tablespace_name,a.file_name
  266. /

  267. Output from option Number 2:
  268. TABLESPACE_NAME FILE_NAME HIGHWATER
  269. --------------- -------------------------------------------------- -----------
  270. BIGPARTYWEEK1 /ots1/app/oracle/product/8.1.7/dbs/bw1.dbf 49152
  271. IFS_LOB_N /ots3/oradata/v817/oradata/v817/ifs_lob_n.dbf 157294592
  272. IFS_MAIN /ots3/oradata/v817/oradata/v817/ifs_main.dbf 23027712
  273. OEM_REPOSITORY /ots1/oradata/v817/oradata/v817/oem_repository.dbf 56492032
  274. RBS /ots1/oradata/v817/oradata/v817/rbs01.dbf 230170624
复制代码

回复 只看该作者 道具 举报

17#
发表于 2011-12-27 16:09:09
是这样的,目前还没有找到解决办法,我的也是一样,我的system还占用了60G呢,真正还不到1G,痛苦死了,希望12g在这方面能改进,到时只要一命令就可将后面的整到前面,然后再收缩就可以了,目前写在最后无法自动往前整,而我们又不太放心手工整这些会不会有问题,所以引发了这个问题。

回复 只看该作者 道具 举报

您需要登录后才可以回帖 登录 | 注册

QQ|手机版|Archiver|Oracle数据库数据恢复、性能优化

GMT+8, 2024-12-23 23:49 , Processed in 0.085715 second(s), 21 queries .

Powered by Discuz! X2.5

© 2001-2012 Comsenz Inc.

回顶部
TEL/電話+86 13764045638
Email service@parnassusdata.com
QQ 47079569