传输表空间综述:
不论是数据字典管理的表空间还是本地管理的表空间,都可以使用传输表空间技术;从9i开始传输表空间不需要在源数据库和目标数据库之间具有同样的DB_BLOCK_SIZE块大小;使用传输表空间迁移数据比使用数据导入导出工具迁移数据的速度要快,这是因为传输表空间只是复制包含实际数据的数据文件到目标数据库的指定位置,而使用数据导入导出工具将传输表空间对象的元数据到目标数据库。
我们知道Oracle利用imp/impdp传输表空间transport_tablespace需要满足以下条件:
1.字符集相同
2.要导出的表空间必须是read only,而且是自包含的,就是说该表空间的对象不能依赖其他表空间。
3.先导出源数据,传输表空间的数据文件拷贝到另一个数据库相应目录下。
也可以使用rman传输表空间,但是其过程相对复杂的多,首先要备份全库,归档日志和控制文件,最后还得用imp/impdp进行导入,但是利用rman的好处是可以不用把目标表空间read only;
关于传输表空间的一下限制:
(1)10g之前源数据库和目标数据库必须处于相同的平台。10g以后可以用RMAN命令修改数据文件实现跨平台移动表空间。
(2)对于源数据库和目标数据库版本不同时,源数据库的版本必须低于目标数据库。
(3)两边设置的数据库字符集和国家字符集必须一致。
(4)目标数据库不能存在需要导入的表空间,否则报错,他自己会创建该表空间。
(5)源数据库和目标数据库的blocksize必须一致(9i前)。9i之后blocksize可以不一致了。
整体的操作步骤:
1、如果是跨平台的表空间传输,需要检查两个平台支持的字节存储顺序,检查方法见如上文所述,如果可以确定源数据库和目标数据库属于同一平台,可以省略此步骤;
2、选择自包含的(self-contained)表空间,这里的限制相对于使用数据泵来说比较变态,实验中将会有一些粗略的介绍。
3、将源数据库上的选定表空间修改为read-only状态,使用expde工具生成传输表空间(集)。 //在这一步,如果两个平台间的字节存储次序不同,还需完成字节存储次序的转换
4、传输表空间及与表空间对应数据文件 (使用操作系统命令、ftp命令等方式)到目标数据库。 //字节存储次序的转换也可以在这一步完成
5、将源数据库的表空间恢复为read-write状态(可选)
6、在目标数据库,使用impdp工具导入表空间(集)
下面展示具体的操作过程:
环境情况:
Source 端:
操作系统: OracleLinux 6.2 64位
endianness格式: little
数据库版本:11.2.0.3
Target 端:
操作系统:OracleLinux 6.2 64位
endianness 格式: little
数据库版本:11.2.0.3
1、查看操作系统endianness格式
col platform_name for a40
SELECT *
FROM V$TRANSPORTABLE_PLATFORM
ORDER BY PLATFORM_ID;
PLATFORM_ID PLATFORM_NAME ENDIAN_FORMAT
----------- ---------------------------------------- --------------
1 Solaris[tm] OE (32-bit) Big
2 Solaris[tm] OE (64-bit) Big
3 HP-UX (64-bit) Big
4 HP-UX IA (64-bit) Big
5 HP Tru64 UNIX Little
6 AIX-Based Systems (64-bit) Big
7 Microsoft Windows IA (32-bit) Little
8 Microsoft Windows IA (64-bit) Little
9 IBM zSeries Based Linux Big
10 Linux IA (32-bit) Little
11 Linux IA (64-bit) Little
12 Microsoft Windows x86 64-bit Little
13 Linux x86 64-bit Little
15 HP Open VMS Little
16 Apple Mac OS Big
17 Solaris Operating System (x86) Little
18 IBM Power Based Linux Big
19 HP IA Open VMS Little
20 Solaris Operating System (x86-64) Little
21 Apple Mac OS (x86-64) Little
20 rows selected.
--分别查看 source 端 和target端操作系统endianness格式
--source
SELECT d.PLATFORM_NAME,
ENDIAN_FORMAT
FROM V$TRANSPORTABLE_PLATFORM tp, V$DATABASE d
WHERE tp.PLATFORM_NAME =d.PLATFORM_NAME;
PLATFORM_NAME ENDIAN_FORMAT
---------------------------------------- --------------
Linux x86 64-bit Little
--target
SELECT d.PLATFORM_NAME,
ENDIAN_FORMAT
FROM V$TRANSPORTABLE_PLATFORM tp, V$DATABASE d
WHERE tp.PLATFORM_NAME =d.PLATFORM_NAME;
PLATFORM_NAME ENDIAN_FORMAT
---------------------------------------- --------------
Linux x86 64-bit Little
2、在source端创建测试表空间
select tablespace_name,
status
from dba_tablespaces;
TABLESPACE_NAME STATUS
------------------------------ ---------
SYSTEM ONLINE
UNDOTBS1 ONLINE
SYSAUX ONLINE
TEMPTS1 ONLINE
USERS ONLINE
OUTLN ONLINE
6 rows selected.
select file_name from dba_data_files;
FILE_NAME
------------------------------------------------
/u01/app/oracle/oradata/normal/system01.dbf
/u01/app/oracle/oradata/normal/undotbs01.dbf
/u01/app/oracle/oradata/normal/sysaux01.dbf
/u01/app/oracle/oradata/normal/users01.dbf
/u01/app/oracle/oradata/normal/undotbs02.dbf
/u01/app/oracle/oradata/normal/system02.dbf
/u01/app/oracle/oradata/normal/outln01.dbf
7 rows selected.
--创建表空间创建表空间 tset
create tablespace tset datafile '/u01/app/oracle/oradata/normal/test01.dbf' size 50M;
Tablespace created.
--创建用户source_test,并指定表空间
--在source端
create user source_test
identified by oracle
default tablespace tset
temporary tablespace TEMPTS1;
User created.
grant connect,resource to source_test;
Grant succeeded.
--在target端(暂时只先创建用户)
create user target_test identified by oracle temporary tablespace TEMPTS1;
User created.
grant connect,resource to target_test;
Grant succeeded.
--创建测试表
SQL> conn source_test/oracle
Connected.
SQL> create table t1(id number, name varchar2(30));
Table created.
SQL> insert into t1 values(1, 'AAAAA');
1 row created.
SQL> insert into t1 values(2, 'BBBBB');
1 row created.
SQL> commit;
Commit complete.
select * from t1;
1.
2. ID NAME
3. ---------- ------------------------------
4. 1 AAAAA
5. 2 BBBBB
3、在source端和target端创建 backup 的目录
[oracle@normal ~]$ mkdir -p /u01/backup
[oracle@normal ~]$ ls -l /u01
total 24
drwxr-xr-x 3 oracle oinstall 4096 Jul 28 12:31 app
drwxr-xr-x 2 oracle oinstall 4096 Sep 14 16:21 backup
SQL> show user
USER is "SYS"
SQL> create directory backup as '/u01/backup'
Directory created.
SQL> col owner format a5
SQL> col directory_name format a25
SQL> col DIRECTORY_PATH format a50
SQL> select * from dba_directories;
OWNER DIRECTORY_NAME DIRECTORY_PATH
----- ------------------------- --------------------------------------------------
SYS BACKUP /u01/backup
SYS OUTLN_DIR /home/oracle
SYS DATA_PUMP_DIR /u01/app/oracle/product/11.2.0/db_1/rdbms/log/
SYS ORACLE_OCM_CONFIG_DIR /u01/app/oracle/product/11.2.0/db_1/ccr/state
SQL> GRANT read, write ON DIRECTORY backup TO source_test;
Grant succeeded.
--在target端
[oracle@test ~]$ mkdir -p /u01/backup
[oracle@test ~]$ ls -l /u01
total 24
drwxr-xr-x 3 oracle oinstall 4096 Aug 28 09:09 app
drwxr-xr-x 2 oracle oinstall 4096 Sep 14 16:40 backup
SQL> show user
USER is "SYS"
SQL> create directory backup as '/u01/backup'
Directory created.
SQL> col owner format a5
SQL> col directory_name format a25
SQL> col DIRECTORY_PATH format a50
SQL> select * from dba_directories;
OWNER DIRECTORY_NAME DIRECTORY_PATH
----- ------------------------- --------------------------------------------------
SYS BACKUP /u01/backup
SYS OUTLN_DIR /home/oracle
SYS DATA_PUMP_DIR /u01/app/oracle/product/11.2.0/db_1/rdbms/log/
SYS ORACLE_OCM_CONFIG_DIR /u01/app/oracle/product/11.2.0/db_1/ccr/state
SQL> GRANT read, write ON DIRECTORY backup TO target_test;
Grant succeeded.
4、检查表空间自包含(就是改表空间里的数据没有和其他表空间数据有关联,如果有关联会报错)
SQL> execute dbms_tts.transport_set_check('TSET', TRUE);
PL/SQL procedure successfully completed.
--查看自包含验证结果:
SQL> select * from transport_set_violations;
no rows selected
--没有记录说明没有错
5、将表空间TSET设置成read?-only,生成Transportable Tablespace Set之后就可以改成read write 了。
SQL> alter tablespace TSET read only;
Tablespace altered.
select tablespace_name, status from dba_tablespaces;
TABLESPACE_NAME STATUS
------------------------------ ---------
SYSTEM ONLINE
UNDOTBS1 ONLINE
SYSAUX ONLINE
TEMPTS1 ONLINE
USERS ONLINE
OUTLN ONLINE
TSET READ ONLY
7 rows selected.
6、生成:Transportable Tablespace Set ,
Transportable Tablespace Set有两部分:
1.expdp 导出的表空间的metadata
2.还有就是表空间对应的数据文件
--expdp 导出的表空间的metadata
[oracle@normal normal]$ pwd
/u01/app/oracle/oradata/normal
[oracle@normal normal]$ ll
total 2294664
-rw-r----- 1 oracle oinstall 9781248 Sep 14 16:46 control01.ctl
drwx------ 2 oracle oinstall 16384 Aug 22 12:44 lost+found
-rw-r----- 1 oracle oinstall 20979712 Sep 14 15:52 outln01.dbf
-rw-r----- 1 oracle oinstall 52429312 Sep 14 16:45 redo01a.log
-rw-r----- 1 oracle oinstall 52429312 Sep 14 16:45 redo01b.log
-rw-r----- 1 oracle oinstall 52429312 Sep 14 15:52 redo02a.log
-rw-r----- 1 oracle oinstall 52429312 Sep 14 15:52 redo02b.log
-rw-r----- 1 oracle oinstall 52429312 Sep 14 15:52 redo03a.log
-rw-r----- 1 oracle oinstall 52429312 Sep 14 15:52 redo03b.log
-rw-r--r-- 1 oracle oinstall 22633 Aug 22 17:00 su.lst
-rw-r----- 1 oracle oinstall 340795392 Sep 14 16:40 sysaux01.dbf
-rw-r----- 1 oracle oinstall 340795392 Sep 14 16:43 system01.dbf
-rw-r----- 1 oracle oinstall 314580992 Sep 14 16:43 system02.dbf
-rw-r----- 1 oracle oinstall 20979712 Sep 14 15:53 temp01.dbf
-rw-r----- 1 oracle oinstall 52436992 Sep 14 15:53 temp02.dbf
-rw-r----- 1 oracle oinstall 52436992 Sep 14 16:31 test01.dbf
-rw-r----- 1 oracle oinstall 209723392 Sep 14 16:43 undotbs01.dbf
-rw-r----- 1 oracle oinstall 209723392 Sep 14 16:40 undotbs02.dbf
-rw-r----- 1 oracle oinstall 524296192 Sep 14 15:52 users01.dbf
[oracle@normal normal]$ expdp dumpfile=test01.dmp directory=backup
transport_tablespaces=TSET transport_full_check=y logfile=TSET.log
Export: Release 11.2.0.3.0 - Production on Sun Sep 14 16:54:30 2014
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
Username: / as sysdba
Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Starting "SYS"."SYS_EXPORT_TRANSPORTABLE_01": /********/ AS SYSDBA dumpfile=test01.dmp directory=backup transport_tablespaces=TSET transport_full_check=y logfile=TSET.log
Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK
Processing object type TRANSPORTABLE_EXPORT/TABLE
Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK
Master table "SYS"."SYS_EXPORT_TRANSPORTABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SYS.SYS_EXPORT_TRANSPORTABLE_01 is:
/u01/backup/test01.dmp
******************************************************************************
Datafiles required for transportable tablespace TSET:
/u01/app/oracle/oradata/normal/test01.dbf
Job "SYS"."SYS_EXPORT_TRANSPORTABLE_01" successfully completed at 16:55:13
[oracle@normal normal]$ ls -l /u01/backup/
total 80
-rw-r----- 1 oracle oinstall 77824 Sep 14 16:55 test01.dmp
-rw-r--r-- 1 oracle oinstall 1160 Sep 14 16:55 TSET.log
7、将Transportable Tablespace set 传送到Target端
1)将表空间test 对应的数据文件copy到Target 对应的ORADATA目录下。
2)将expdp 导出的表空间metadta 数据copy 到Target 端的backup 目录下
--将表空间test 对应的数据文件copy到Target 对应的ORADATA目录下,这个路径可以和source不样。
[oracle@normal normal]$ scp /u01/backup/test01.dmp 192.168.137.12:/u01/backup
[email protected] s password:
test01.dmp 100% 76KB 76.0KB/s 00:00
--将expdp 导出的表空间metadta 数据copy 到Target 端的backup 目录下
[oracle@normal normal]$ scp test01.dbf 192.168.137.12:/u01/app/oracle/oradata/normal/test01.dbf
[email protected] s password:
test01.dbf 100% 50MB 16.7MB/s 00:03
--在target端查看文件是否已经传输
[oracle@test ~]$ ll /u01/backup/
total 76
-rw-r----- 1 oracle oinstall 77824 Sep 14 17:03 test01.dmp
[oracle@test ~]$ ll $ORACLE_BASE/oradata/normal/test01.dbf
-rw-r----- 1 oracle oinstall 52436992 Sep 14 17:04 /u01/app/oracle/oradata/normal/test01.dbf
8、在Target 系统上Import 表空间的metadata(使用target_test用户,需要用到remap_schema)
[oracle@test ~]$ impdp directory=backup dumpfile=test01.dmp transport_datafiles=/u01/app/oracle/oradata/normal/test01.dbf remap_schema=source_test:target_test logfile=test.log
Import: Release 11.2.0.3.0 - Production on Sun Sep 14 17:09:25 2014
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
Username: / as sysdba
Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Master table "SYS"."SYS_IMPORT_TRANSPORTABLE_01" successfully loaded/unloaded
Starting "SYS"."SYS_IMPORT_TRANSPORTABLE_01": /********/ AS SYSDBA directory=backup dumpfile=test01.dmp transport_datafiles=/u01/app/oracle/oradata/normal/test01.dbf remap_schema=source_test:target_test logfile=test.log
Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK
Processing object type TRANSPORTABLE_EXPORT/TABLE
Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK
Job "SYS"."SYS_IMPORT_TRANSPORTABLE_01" successfully completed at 17:09:55
9、查看并修改表空间状态
select tablespace_name,
status
from dba_tablespaces;
TABLESPACE_NAME STATUS
------------------------------ ---------
SYSTEM ONLINE
UNDOTBS1 ONLINE
SYSAUX ONLINE
TEMPTS1 ONLINE
USERS ONLINE
OUTLN ONLINE
TSET READ ONLY
7 rows selected.
SQL> alter tablespace TSET read write;
Tablespace altered.
10、验证
SQL> conn target_test/oracle
Connected.
SQL> select * from t1;
1.
ID NAME
---------- ------------------------------
1 AAAAA
2 BBBBB
总结:
(一):如果是跨平台了,则需要进行平台转换,可以在源端操作也可以在目的端操作。
例如:
源端:
SQL>SELECTd.PLATFORM_NAME,ENDIAN_FORMATFROMV$TRANSPORTABLE_PLATFORM tp,V$DATABASE dWHEREtp.PLATFORM_NAME=d.PLATFORM_NAME;
SQL>PLATFORM_NAME ENDIAN_FORMAT
----------------------------- --------------
Linux x8664-bit Little
目标端:
SQL>SELECTd.PLATFORM_NAME,ENDIAN_FORMATFROMV$TRANSPORTABLE_PLATFORM tp,V$DATABASEdWHEREtp.PLATFORM_NAME=d.PLATFORM_NAME;
PLATFORM_NAME ENDIAN_FORMAT
---------------------------------------- --------------
Solaris Operating System (x86-64) Little
那么需要平台转换:
如果在源端转换:
RMAN>converttablespace'TTBS1' toplatform="Solaris Operating System (x86-64)" db_file_name_convert='/u01/app/oracle/oradata/silent/ttbs1.dbf','/tmp/ttbs1.dbf'
Starting conversion at source at12-AUG-12
using channel ORA_DISK_1
channel ORA_DISK_1: starting datafile conversion
input datafilefilenumber=00005name=/u01/app/oracle/oradata/silent/ttbs1.dbf
converted datafile=/tmp/ttbs1.dbf
channel ORA_DISK_1: datafile conversion complete, elapsed time:00:00:16
Finished conversion at source at12-AUG-12
如果在target端转换,方法如下:
RMAN>CONVERTDATAFILE'/u01/app/oracle/oradata/sun/ttbs1.dbf'TOPLATFORM="Solaris Operating System (x86-64)"FROMPLATFORM="Linux x8664-bit" DB_FILE_NAME_CONVERT="/u01/app/oracle/oradata/sun/","/tmp/";
Starting conversion at target at12-AUG-12
using channel ORA_DISK_1
channel ORA_DISK_1: starting datafile conversion
inputfilename=/u01/app/oracle/oradata/sun/ttbs1.dbf
converted datafile=/tmp/ttbs1.dbf
channel ORA_DISK_1: datafile conversion complete, elapsed time:00:00:14
Finished conversion at target at12-AUG-12
(二):可以使用参数:remap_tablespace=ttbs1:ttbs2,来修改传过来的表空间名字。
心得:
可传输表空间加快了数据迁移的速度,可是使用逻辑导入导出来完成表空间传输需要将该表空间置为read only;虽然使用rman技术来完成表空间传输可以不将该表空间置为read only。但是用rman技术的过程相对非常复杂,这无疑导致该技术在生产环境使用的频率不大。多数人还是选择直接数据泵的方式来完成一个表空间的迁移工作。