<<Back to Oracle DATAPUMP Main Page
EXPDP SOURCE_EDITION
Default: the default database edition on the systemPurpose
Specifies the database edition from which objects will be exported.
Syntax and Description
SOURCE_EDITION=edition_name
This parameter is only useful if there are two or more versions of the same versionable objects in the database. Check Out here Edition Based Redefinition in Oracle Database 11g Release 2 for an overview of Editioning in oracle
Environment Prepration for expdp source_edition demonstration
SQL> grant create any edition to test;
Grant succeeded.
SQL>select USERNAME,EDITIONS_ENABLED from dba_users where USERNAME='TEST';
USERNAME E
-------------------- -
TEST N
SQL> create edition my_exp_edition ;
Edition created.
SQL> create edition my_exp_edition2 ;
Edition created.
SQL> SELECT * FROM dba_editions;
EDITION_NAME PARENT_EDITION_NAME USA
--------------- -------------------- ---
ORA$BASE YES
MY_EXP_EDITION ORA$BASE YES
MY_EXP_EDITION2 MY_EXP_EDITION YES
SQL> alter user test enable editions;
User altered.
SQL> alter session set edition=MY_EXP_EDITION;
Session altered.
SQL> show edition;EDITION
------------------------------
MY_EXP_EDITION
SQL> create editioning view MY_EXP_EDITION_V as select * from EXP_EDITION_TEST;
View created.
SQL> alter session set edition=MY_EXP_EDITION2;
Session altered.
SQL> create or replace editioning view MY_EXP_EDITION_V as select name from EXP_EDITION_TEST;
View created.
SQL> select * from MY_EXP_EDITION_V;
NAME
--------------------
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
NAME
--------------------
TEST
TEST
TEST2
14 rows selected.
SQL> alter session set edition=MY_EXP_EDITION;
Session altered.
SQL> select * from MY_EXP_EDITION_V;
ID NAME
---------- --------------------
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
1 TEST
ID NAME
---------- --------------------
1 TEST
1 TEST
1 TEST2
14 rows selected.
Note: As you can see now we have 2 editions of MY_EXP_EDITION_V view one with column id and name and the other with just name
Lets Export the TEST SCHEMA with specific edition using SOURCE_EIDTION parameter
$ cat exp.par
DIRECTORY=EXP
DUMPFILE=EXP.DMP
LOGFILE=EXP.LOG
SCHEMAS=TEST
SOURCE_EDITION=MY_EXP_EDITION2
REUSE_DUMPFILES=Y
$ expdp test@PDB01 parfile=exp.par
Export: Release 12.2.0.1.0 - Production on Tue Nov 13 11:15:15 2018
Copyright (c) 1982, 2017, Oracle and/or its affiliates. All rights reserved.
Password:
Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
Starting "TEST"."SYS_EXPORT_SCHEMA_01": test/********@PDB01 parfile=exp.par
Processing object type SCHEMA_EXPORT/TABLE/TABLE_DATA
Processing object type SCHEMA_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type SCHEMA_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type SCHEMA_EXPORT/STATISTICS/MARKER
Processing object type SCHEMA_EXPORT/USER
Processing object type SCHEMA_EXPORT/SYSTEM_GRANT
Processing object type SCHEMA_EXPORT/ROLE_GRANT
Processing object type SCHEMA_EXPORT/DEFAULT_ROLE
Processing object type SCHEMA_EXPORT/TABLESPACE_QUOTA
Processing object type SCHEMA_EXPORT/PRE_SCHEMA/PROCACT_SCHEMA
Processing object type SCHEMA_EXPORT/DB_LINK
Processing object type SCHEMA_EXPORT/TABLE/TABLE
Processing object type SCHEMA_EXPORT/TABLE/COMMENT
Processing object type SCHEMA_EXPORT/VIEW/VIEW
Processing object type SCHEMA_EXPORT/TABLE/INDEX/INDEX
Processing object type SCHEMA_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
. . exported "TEST"."EMP" 5.531 KB 5 rows
. . exported "TEST"."EMP1" 5.476 KB 1 rows
. . exported "TEST"."TEST" 5.476 KB 1 rows
. . exported "TEST"."EMP_EDITION2" 5.484 KB 1 rows
. . exported "TEST"."EXP_EDITION_TEST" 5.648 KB 14 rows
Master table "TEST"."SYS_EXPORT_SCHEMA_01" successfully loaded/unloaded
******************************************************************************
Dump file set for TEST.SYS_EXPORT_SCHEMA_01 is:
/u01/dbatst1/stage/EXP.DMP
Job "TEST"."SYS_EXPORT_SCHEMA_01" successfully completed at Tue Nov 13 11:16:15 2018 elapsed 0 00:00:56
Let us perform an Import using the above export DUMP and see if the SOURCE_EDITION parameter was used while exporting.
$ cat imp.par
DIRECTORY=EXP
DUMPFILE=EXP.DMP
REMAP_SCHEMA=TEST:TEST_ED
LOGFILE=IMP.LOG
$ impdp test@PDB01 parfile=imp.par
Import: Release 12.2.0.1.0 - Production on Tue Nov 13 11:19:26 2018
Copyright (c) 1982, 2017, Oracle and/or its affiliates. All rights reserved.
Password:
Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
Master table "TEST"."SYS_IMPORT_FULL_01" successfully loaded/unloaded
Starting "TEST"."SYS_IMPORT_FULL_01": test/********@PDB01 parfile=imp.par
Processing object type SCHEMA_EXPORT/USER
Processing object type SCHEMA_EXPORT/SYSTEM_GRANT
Processing object type SCHEMA_EXPORT/ROLE_GRANT
Processing object type SCHEMA_EXPORT/DEFAULT_ROLE
Processing object type SCHEMA_EXPORT/TABLESPACE_QUOTA
Processing object type SCHEMA_EXPORT/PRE_SCHEMA/PROCACT_SCHEMA
Processing object type SCHEMA_EXPORT/DB_LINK
Processing object type SCHEMA_EXPORT/TABLE/TABLE
Processing object type SCHEMA_EXPORT/TABLE/TABLE_DATA
. . imported "TEST_ED"."EMP" 5.531 KB 5 rows
. . imported "TEST_ED"."EMP1" 5.476 KB 1 rows
. . imported "TEST_ED"."TEST" 5.476 KB 1 rows
. . imported "TEST_ED"."EMP_EDITION2" 5.484 KB 1 rows
. . imported "TEST_ED"."EXP_EDITION_TEST" 5.648 KB 14 rows
Processing object type SCHEMA_EXPORT/VIEW/VIEW
Processing object type SCHEMA_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type SCHEMA_EXPORT/STATISTICS/MARKER
Job "TEST"."SYS_IMPORT_FULL_01" successfully completed at Tue Nov 13 11:19:52 2018 elapsed 0 00:00:24
SQL> select object_name ,object_type from dba_objects where owner='TEST_ED' and object_type='VIEW';
OBJECT_NAME OBJECT_TYPE
------------------------------ -----------------------
MY_EXP_EDITION_V VIEW
SQL>
SQL> select * from MY_EXP_EDITION_V;
NAME
--------------------
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
TEST
NAME
--------------------
TEST
TEST
TEST2
14 rows selected.
As you can see only the 2nd edition of the view was exported because we have specified the parameter SOURCE_EDITION=MY_EXP_EDITION2 in exp.par file.
NOTE: SOURCE_EDITION parameter is also available in impdp with restrictions as mentioned below.
IMPDP SOURCE_EDITION
Default: the default database edition on the remote node from which objects will be fetched
PurposeSpecifies the database edition on the remote node from which objects will be fetched.
Syntax and DescriptionSOURCE_EDITION=edition_name
Syntax and DescriptionSOURCE_EDITION=edition_name
1> The SOURCE_EDITION parameter is valid on an import operation only when the NETWORK_LINK parameter is also specified.
2> This parameter is only useful if there are two or more versions of the same versionable objects in the database
Comments
Post a Comment