Oracle 19C 传输表空间之-Windows 至 Linux

发布于:2024-05-10 ⋅ 阅读:(23) ⋅ 点赞:(0)

1、源端步骤(Windows )
SQL> col platform_name for a40   
SQL> SELECT * FROM V$TRANSPORTABLE_PLATFORM ORDER BY PLATFORM_ID; 

PLATFORM_ID PLATFORM_NAME                            ENDIAN_FORMAT      CON_ID
----------- ---------------------------------------- -------------- ----------
          1 Solaris[tm] OE (32-bit)                  Big                     0
          2 Solaris[tm] OE (64-bit)                  Big                     0
          3 HP-UX (64-bit)                           Big                     0
          4 HP-UX IA (64-bit)                        Big                     0
          5 HP Tru64 UNIX                            Little                  0
          6 AIX-Based Systems (64-bit)               Big                     0
          7 Microsoft Windows IA (32-bit)            Little                  0
          8 Microsoft Windows IA (64-bit)            Little                  0
          9 IBM zSeries Based Linux                  Big                     0
         10 Linux IA (32-bit)                        Little                  0
         11 Linux IA (64-bit)                        Little                  0

PLATFORM_ID PLATFORM_NAME                            ENDIAN_FORMAT      CON_ID
----------- ---------------------------------------- -------------- ----------
         12 Microsoft Windows x86 64-bit             Little                  0
         13 Linux x86 64-bit                         Little                  0
         15 HP Open VMS                              Little                  0
         16 Apple Mac OS                             Big                     0
         17 Solaris Operating System (x86)           Little                  0
         18 IBM Power Based Linux                    Big                     0
         19 HP IA Open VMS                           Little                  0
         20 Solaris Operating System (x86-64)        Little                  0
         21 Apple Mac OS (x86-64)                    Little                  0
         22 Linux OS (S64)                           Big                     0

21 rows selected.

SQL> 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
---------------------------------------- ----------------------------
Microsoft Windows x86 64-bit             Little

SQL> select file_name from dba_data_files where TABLESPACE_NAME='USERS';

FILE_NAME
--------------------------------------------------------------------------------
C:\APP\DB_DATA\UTBS\USERS01.DBF

SQL> create tablespace test datafile 'C:\APP\DB_DATA\UTBS\test01.dbf' size 1M autoextend on;

Tablespace created.

SQL> create user ahern identified by ahern default tablespace test quota unlimited on test;

User created.

SQL> grant connect,resource to ahern;

Grant succeeded.

SQL> conn ahern/ahern;
Connected.

SQL> create table t1(id number, name varchar2(30)); 

Table created.

SQL> insert into t1 values(1, 'ASDFG'); 

1 row created.

SQL> insert into t1 values(2, 'QWERT');  

1 row created.

SQL> commit;

Commit complete.

SQL> select * from t1;

        ID NAME
---------- ------------------------------
         1 ASDFG
         2 QWERT

SQL> conn / as sysdba
Connected.

SQL> create directory dir as 'C:\app\db_dump\';

Directory created.

SQL> grant read,write on directory dir to ahern;

Grant succeeded.

SQL> execute dbms_tts.transport_set_check(ts_list => 'TEST',incl_constraints => TRUE,full_check => TRUE);

PL/SQL procedure successfully completed.

SQL> select * from transport_set_violations;

no rows selected

SQL> alter tablespace TEST read only;

Tablespace altered.

SQL> select tablespace_name,status from dba_tablespaces where tablespace_name='TEST';

TABLESPACE_NAME                STATUS
------------------------------ ---------
TEST                           READ ONLY

expdp sys/oracle dumpfile=test.dmp directory=dir transport_tablespaces=TEST transport_full_check=y logfile=test.log
源端转化
rman target /
convert tablespace 'TEST' 
to platform 'Linux x86 64-bit' 
from platform 'Microsoft Windows x86 64-bit' format 'C:\app\db_dump\%N_%f'
PARALLELISM 8; 

拷贝文件至目标端
cp C:\app\db_dump\test.dmp target_IP:/u01/dump/test.dmp         
cp C:\app\db_dump\TEST_5 target_IP:/u01/app/oracle/oradata/ZZH/TEST_5

2、目标端步骤 (Oel 7.5):
SQL> create user ahern identified by ahern;
SQL> grant connect,resource to ahern;

impdp \'/as sysdba\' directory=dir dumpfile=test.dmp transport_datafiles='/u01/app/oracle/oradata/ZZH/test_5' logfile=test.log
这里也可以使用 remap_schema remap_tablespace 做映射

传输完成后验证数据,以及修改用户权限、默认表空间等:
[oracle@oel ZZH]$ sqlplus ahern/ahern

SQL*Plus: Release 19.0.0.0.0 - Production on Tue May 7 11:28:23 2024
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> select * from t1;

        ID NAME
---------- ------------------------------
         1 ASDFG
         2 QWERT

SQL> 
到此表空间简单传输完成。