[Oracle 10g] 表空间更名

作者:Fenng
日期:24-Oct-2004 
出处:http://www.dbanotes.net
版本:0.1


简单介绍

在 Oracle 10g 以前的版本,更改表空间名字是几乎不可能的事情,除非删除,重新创建,大费周章。Oracle 10g 新添加了一项更改表空间名字的功能,使得更改表空间名字瞬间即可完成。是个较为人性化的功能。

SQL> COL FILE_NAME format a70
SQL> SET linesize 120
SQL> SET pagesize 99
SQL> COL TABLESPACE_NAME format a10
SQL>
SQL> SELECT file_name, tablespace_name FROM dba_data_files;

FILE_NAME                                                              TABLESPACE
---------------------------------------------------------------------- ----------
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/users01.dbf           USERS
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/sysaux01.dbf          SYSAUX
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/undotbs01.dbf         UNDOTBS1
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/system01.dbf          SYSTEM
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/example01.dbf         EXAMPLE
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/foo1.dbf              FOO


6 rows selected.

该命令的语法很简单:

ALTER TABLESPACE tablespacename RENAME TO newtablespacename;

tablespacename 和newtablespacename 分别对应原来的表空间名字和更改后的表空间名字:

实战演练

注意:在操作前后都请做好控制文件的备份工作

SQL>ALTER TABLESPACE foo RENAME TO test;

Tablespace altered.

SQL> SELECT file_name, tablespace_name FROM dba_data_files;

FILE_NAME                                                              TABLESPACE
---------------------------------------------------------------------- ----------
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/users01.dbf           USERS
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/sysaux01.dbf          SYSAUX
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/undotbs01.dbf         UNDOTBS1
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/system01.dbf          SYSTEM
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/example01.dbf         EXAMPLE
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/foo1.dbf              TEST

因为 system 和 sysaux 这两个表空间的特殊性,是不可以更名的:

SQL> ALTER TABLESPACE system RENAME TO mysystem;
ALTER TABLESPACE system RENAME TO mysystem
*
ERROR at line 1:
ORA-00712: cannot rename system tablespace

SQL> ALTER TABLESPACE sysaux RENAME TO mysysaux;
ALTER TABLESPACE sysaux RENAME TO mysysaux
*
ERROR at line 1:
ORA-13502: Cannot rename SYSAUX tablespace

可以对 undo tablespace 重新命名,如果使用的是 spfile ,而不是 pfile, Oracle 会自动对 spfile 中的 undo_tablespace 进行更改(不过要在数据库重新启动之后才可以观察到), 如果使用的是 pfile ,要对其进行手工更改。我们看看 spfile 的变化情况:

SQL> ALTER tablespace undotbs1 RENAME TO undotbs; 

Tablespace altered.

SQL> 
SQL> show parameter pfile 

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
spfile                               string      /u01/app/oracle/product/10.1.0
                                                 /db_1/dbs/spfileTEST.ora
SQL> show parameters undo

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
undo_management                      string      AUTO
undo_retention                       integer     900
undo_tablespace                      string      UNDOTBS1
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area  180355072 bytes
Fixed Size                   777996 bytes
Variable Size             128983284 bytes
Database Buffers           50331648 bytes
Redo Buffers                 262144 bytes
Database mounted.
Database opened.
SQL> show parameters undo

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
undo_management                      string      AUTO
undo_retention                       integer     900
undo_tablespace                      string      UNDOTBS
SQL> 

对脱机表空间的更名是不允许的:

SQL> ALTER TABLESPACE TEST OFFLINE;

Tablespace altered.

SQL> ALTER TABLESPACE test RENAME TO testoffline;              
ALTER TABLESPACE test RENAME TO testoffline
*
ERROR at line 1:
ORA-01135: file 6 accessed for DML/query is offline
ORA-01110: data file 6:
'/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/foo1.dbf'

给出的提示信息很有参考价值:更名操作是要对表空间进行 DML/query 操作的,表空间offline的话,则不可以。

那么如果表空间是只读的会怎么样呢?

SQL> ALTER TABLESPACE TEST ONLINE;

Tablespace altered.

SQL> ALTER TABLESPACE TEST READ ONLY;

Tablespace altered.

SQL> ALTER TABLESPACE test RENAME TO testreadonly;

Tablespace altered.

SQL> list
  1* SELECT file_name, tablespace_name FROM dba_data_files
SQL> /

FILE_NAME                                                              TABLESPACE
---------------------------------------------------------------------- ----------
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/users01.dbf           USERS
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/sysaux01.dbf          SYSAUX
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/undotbs01.dbf         UNDOTBS
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/system01.dbf          SYSTEM
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/example01.dbf         EXAMPLE
/u01/app/oracle/product/10.1.0/db_1/oradata/TEST/foo1.dbf              TESTREADONLY


6 rows selected.

SQL> 

看来数据字典已经更新,不过Oracle会向alert_SID.log 中写入类似如下的日志:

ALTER TABLESPACE test RENAME TO testreadonly                                                 
Sat Nov 13 16:15:21 2004                                                                     
Tablespace 'TEST' is renamed to 'TESTREADONLY'.                                              
Tablespace name change is not propagated to file headersbecause the tablespace is read only. 
Completed: ALTER TABLESPACE test RENAME TO testreadonly 

注意Log里有个细微的小Bug:headersbecause。这是两个词,应该空开的 :-)

更名对 Bigfile 表空间一样有效。

限制条件

应用这个特性有个主要的限制条件:COMPATIBLE 初始化参数要求为 10.0 或者更高才可以

参考信息


Oracle Database Administrator's Guide 10g Release 1 (10.1) Part Number B10739-01 ( Note 62294.1 )



本文作者

Fenng,某美资公司DBA,业余时间混迹于各数据库相关的技术论坛且乐此不疲。 目前关注如何利用ORACLE数据库有效地构建企业应用。对Oracle tuning、troubleshooting有一点研究。
个人技术站点:http://www.dbanotes.net/ 。 可以通过电子邮件 [email protected] 联系到他。

原文出处

http://www.dbanotes.net/Oracle/10g_Rename_Tablespace.htm

回上页<-|->回首页

All Articles (by Fenng) are licensed under a Creative Commons License.
I would welcome any feedback. Please send questions, comments or corrections to [email protected]
Valid XHTML 4.01 / Valid CSS