Chinaunix首页 | 论坛 | 博客
  • 博客访问: 139587
  • 博文数量: 46
  • 博客积分: 3033
  • 博客等级: 中校
  • 技术积分: 550
  • 用 户 组: 普通用户
  • 注册时间: 2008-10-05 16:13
文章分类

全部博文(46)

文章存档

2011年(1)

2010年(8)

2009年(22)

2008年(15)

我的朋友

分类: Oracle

2008-12-26 15:30:13

   摘要:在使用Oracle9i/Oracle10g的自动Undo管理表空间(AUM)特性时,经常会因为各种原因而导致Undo表空间过度扩展。本文通过一则案例诊断,介绍如何收缩过度扩展的Undo表空间,释放占用空间。

    环境:

    OS: Red Hat Enterprise Linux AS release 4 (Nahant)
    DB: Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production

    某日,一台Oracle10gR2数据库报出如下错误:

    ORA-1653: unable to extend table SYSMAN.MGMT_SYSTEM_ERROR_LOG by 8 in  tablespace SYSAUX
    ORA-1653: unable to extend table SYSMAN.MGMT_SYSTEM_ERROR_LOG by 8 in  tablespace SYSAUX
    ORA-1653: unable to extend table SYSMAN.MGMT_SYSTEM_ERROR_LOG by 8 in  tablespace SYSAUX
    ORA-1653: unable to extend table SYSMAN.MGMT_SYSTEM_ERROR_LOG by 8 in  tablespace SYSAUX
    ORA-1653: unable to extend table SYSMAN.MGMT_SYSTEM_ERROR_LOG by 8 in  tablespace SYSAUX

    数据库无法正常使用。

    登陆检查,发现是SYSAUX表空间空间用尽,不能扩展,尝试手工扩展SYSAUX表空间:
[quote]
alter database datafile '+ORADG/danaly/datafile/sysaux.266.600173881' resize 800m
Tue Nov 29 23:31:38 2005
ORA-1237 signalled during: alter database datafile '+ORADG/danaly/datafile/sysaux.266.600173881' resize 800m...
[/quote]
    出现ORA-1237错误,提示空间不足。这时候我们认识到是磁盘空间可能被用完了.

    是谁“偷偷的”用了那么多空间呢(本来有几十个G的Free磁盘空间的)?

    通过如下脚本检查数据库表空间占用空间情况:
[align=center][attach]13566[/attach][/align]
    不幸的发现,UNDO表空间已经扩展至27G,而TEMP表空间也扩展至20G,这2个表空间加起来占用了47G的磁盘空间,导致了空间不足。

    显然曾经有大事务占用了大量的UNDO表空间和Temp表空间,Oracle的AUM(Auto Undo Management)从出生以来就经常出现只扩展,不收缩(shrink)的情况(通常我们可以设置足够的UNDO表空间大小,然后取消其自动扩展属性)。

  现在我们可以采用如下步骤回收UNDO空间:

  1.确认文件
[quote]
SQL> select file_name,bytes/1024/1024 from dba_data_files
  2  where tablespace_name like 'UNDOTBS1';

FILE_NAME
--------------------------------------------------------------------------------
BYTES/1024/1024
---------------
+ORADG/danaly/datafile/undotbs1.265.600173875
          27810
[/quote]
  2.检查UNDO Segment状态
[quote]
SQL> select usn,xacts,rssize/1024/1024/1024,hwmsize/1024/1024/1024,shrinks
  2  from v$rollstat order by rssize;

       USN      XACTS RSSIZE/1024/1024/1024 HWMSIZE/1024/1024/1024    SHRINKS
---------- ---------- --------------------- ---------------------- ----------
         0          0            .000358582             .000358582          0
         2          0            .071517944             .071517944          0
         3          0             .13722229              .13722229          0
         9          0            .236984253             .236984253          0
        10          0            .625144958             .625144958          0
         5          1            1.22946167             1.22946167          0
         8          0            1.27175903             1.27175903          0
         4          1            1.27895355             1.27895355          0
         7          0            1.56770325             1.56770325          0
         1          0            2.02474976             2.02474976          0
         6          0             2.9671936              2.9671936          0

11 rows selected.
[/quote]
  3.创建新的UNDO表空间
[quote]
SQL> create undo tablespace undotbs2;

Tablespace created.
[/quote]
  4.切换UNDO表空间为新的UNDO表空间
[quote]
SQL> alter system set undo_tablespace=undotbs2 scope=both;

System altered.
[/quote]
  此处使用spfile需要注意,以前曾经记录过这样一个案例,Oracle诊断案例-Spfile案例一则。另外,如果使用的RAC环境,请注意,修改spfile时,要指定sid参数。

  5.等待原UNDO表空间所有UNDO SEGMENT OFFLINE
[quote]
SQL> select usn,xacts,status,rssize/1024/1024/1024,hwmsize/1024/1024/1024,shrinks
  2 from v$rollstat order by rssize;


       USN      XACTS STATUS          RSSIZE/1024/1024/1024 HWMSIZE/1024/1024/1024    SHRINKS
---------- ---------- --------------- --------------------- ---------------------- ----------
        14          0 ONLINE                     .000114441             .000114441          0
        19          0 ONLINE                     .000114441             .000114441          0
        11          0 ONLINE                     .000114441             .000114441          0
        12          0 ONLINE                     .000114441             .000114441          0
        13          0 ONLINE                     .000114441             .000114441          0
        20          0 ONLINE                     .000114441             .000114441          0
        15          1 ONLINE                     .000114441             .000114441          0
        16          0 ONLINE                     .000114441             .000114441          0
        17          0 ONLINE                     .000114441             .000114441          0
        18          0 ONLINE                     .000114441             .000114441          0
         0          0 ONLINE                     .000358582             .000358582          0

       USN      XACTS STATUS          RSSIZE/1024/1024/1024 HWMSIZE/1024/1024/1024    SHRINKS
---------- ---------- --------------- --------------------- ---------------------- ----------
         6          0 PENDING OFFLINE             2.9671936              2.9671936          0

12 rows selected.
[/quote]
  等候一段时间,再次查看:
[quote]
11:32:11 SQL> /

       USN      XACTS STATUS          RSSIZE/1024/1024/1024 HWMSIZE/1024/1024/1024    SHRINKS
---------- ---------- --------------- --------------------- ---------------------- ----------
        15          1 ONLINE                     .000114441             .000114441          0
        11          0 ONLINE                     .000114441             .000114441          0
        12          0 ONLINE                     .000114441             .000114441          0
        13          0 ONLINE                     .000114441             .000114441          0
        14          0 ONLINE                     .000114441             .000114441          0
        20          0 ONLINE                     .000114441             .000114441          0
        16          0 ONLINE                     .000114441             .000114441          0
        17          0 ONLINE                     .000114441             .000114441          0
        18          0 ONLINE                     .000114441             .000114441          0
        19          0 ONLINE                     .000114441             .000114441          0
         0          0 ONLINE                     .000358582             .000358582          0

11 rows selected.

Elapsed: 00:00:00.00
[/quote]
  6.删除原UNDO表空间
[quote]
11:34:00 SQL> drop tablespace undotbs1 including contents;

Tablespace dropped.

Elapsed: 00:00:03.13
[/quote]
  7.检查空间情况

  由于我使用的ASM管理,可以使用10gR2提供的信工具asmcmd来察看空间占用情况.
[quote]
[oracle@danaly ~]$ export ORACLE_SID=+ASM
[oracle@danaly ~]$ asmcmd
ASMCMD> du
Used_MB      Mirror_used_MB
  21625               21625
ASMCMD> exit
[/quote]
  至此空间已经释放。

阅读(1064) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~