Can you EXCLUDE tablespaces from Full Transportable Export/Import?

Question: Can you EXCLUDE one or more tablespaces when doing a Full Transportable Export/Import?

First of all, this question came up already twice in real world customer migrations. So it’s not a totally unusual question. In one case a tablespace called USERS got precreated and some data did get stored. In the second case we did use RMAN incremental backups to migrate a very large database (>100TB) and some tablespaces weren’t part of the backup set.

I did brainstorm with Roy – and I dug into my notes from some years ago when the question was raised to me as part of a migration project to Oracle 12.1.0.1.

Roy and I had basically 2 main approaches to validate.

  1. Run expdp with FULL=Y and TRANSPORTABLE=ALWAYS but EXCLUDE some tablespaces
  2. Run expdp with FULL=Y and TRANSPORTABLE=ALWAYS but EXCLUDE some tablespaces during impdp only

In addition for the customer case where some tablespaces where initially not included into the RMAN Incremental Backupset strategy, the files for these tablespaces can be copied (and converted) in addition. The impdp parameter file will need to take care of it.

First of all, here’s my test setup. The two tablespaces MIKE1 and MIKE2 are the ones I will treat separately.

SQL> select status, tablespace_name from dba_tablespaces;

STATUS	  TABLESPACE_NAME
--------- ------------------------------
ONLINE	  SYSTEM
ONLINE	  SYSAUX
ONLINE	  UNDOTBS1
ONLINE	  TEMP
READ ONLY USERS
ONLINE	  MIKE1
ONLINE	  MIKE2

SQL> create directory oradump as '/home/oracle';
SQL> grant read, write on directory oradump to SYSTEM;

SQL> EXEC SYS.DBMS_TTS.TRANSPORT_SET_CHECK(ts_list => 'MIKE1, MIKE2', incl_constraints => TRUE);
PL/SQL procedure successfully completed.

SQL> SELECT * FROM transport_set_violations;
no rows selected

Case 1 – Run expdp but EXCLUDE some tablespaces

l will use this par file:

directory=oradump
dumpfile=exp.dmp
logfile=exp.log
transportable=always
full=y
metrics=y
version=12
exclude=table_statistics,index_statistics
exclude=tablespace:"IN ('MIKE1', 'MIKE2')"

Now invoking Data Pump with expdp:

$ expdp system/oracle parfile=exp.par

Export: Release 11.2.0.4.0 - Production on Tue May 16 13:17:41 2017
Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
With the Partitioning, Oracle Label Security, OLAP, Data Mining
and Real Application Testing options
Starting "SYSTEM"."SYS_EXPORT_FULL_01":  system/******** parfile=ex.par 
Startup took 1 seconds
Estimate in progress using BLOCKS method...
Processing object type DATABASE_EXPORT/PLUGTS_FULL/FULL/PLUGTS_TABLESPACE
Processing object type DATABASE_EXPORT/PLUGTS_FULL/PLUGTS_BLK
     Completed 1 PLUGTS_BLK objects in 1 seconds
Processing object type DATABASE_EXPORT/EARLY_OPTIONS/VIEWS_AS_TABLES/TABLE_DATA
     Estimated 1 TABLE_DATA objects in 1 seconds

[...]

     Completed 1 DATABASE_EXPORT/EARLY_OPTIONS/VIEWS_AS_TABLES/TABLE_DATA objects in 0 seconds
     Completed 30 DATABASE_EXPORT/NORMAL_OPTIONS/TABLE_DATA objects in 1 seconds
     Completed 5 DATABASE_EXPORT/NORMAL_OPTIONS/VIEWS_AS_TABLES/TABLE_DATA objects in 0 seconds
     Completed 59 DATABASE_EXPORT/SCHEMA/TABLE/TABLE_DATA objects in 0 seconds
Master table "SYSTEM"."SYS_EXPORT_FULL_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SYSTEM.SYS_EXPORT_FULL_01 is:
  /home/oracle/exp.dmp
******************************************************************************
Datafiles required for transportable tablespace USERS:
  /u02/oradata/FTEX/users01.dbf
Job "SYSTEM"."SYS_EXPORT_FULL_01" successfully completed at Tue May 16 13:18:37 2017 elapsed 0 00:00:56

As next step I copy the datafile(s) to the destination’s directory and configure my import par file:

directory=oradump
dumpfile=exp.dmp
logfile=imp.log
metrics=y
logtime=all
transport_datafiles='/u02/oradata/DB12/users01.dbf'

And importing into my new destination database with impdp:

$ impdp system/oracle parfile=imp.par

Import: Release 12.1.0.2.0 - Production on Tue May 16 13:52:46 2017
Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved.

Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
16-MAY-17 13:57:08.681: Startup took 0 seconds
16-MAY-17 13:57:09.299: Master table "SYSTEM"."SYS_IMPORT_TRANSPORTABLE_01" successfully loaded/unloaded
16-MAY-17 13:57:09.544: Source time zone is +02:00 and target time zone is +01:00.
16-MAY-17 13:57:09.546: Starting "SYSTEM"."SYS_IMPORT_TRANSPORTABLE_01": system/******** parfile=imp.par
16-MAY-17 13:57:09.596: Processing object type DATABASE_EXPORT/PRE_SYSTEM_IMPCALLOUT/MARKER

[...]

16-MAY-17 13:57:45.160: Processing object type DATABASE_EXPORT/END_PLUGTS_BLK
16-MAY-17 13:57:45.238: Completed 1 PLUGTS_BLK objects in 0 seconds
16-MAY-17 13:57:45.243: Processing object type DATABASE_EXPORT/FINAL_POST_INSTANCE_IMPCALLOUT/MARKER
16-MAY-17 13:57:47.868: Completed 1 MARKER objects in 2 seconds
16-MAY-17 13:57:47.875: Processing object type DATABASE_EXPORT/SCHEMA/POST_SCHEMA/PROCACT_SCHEMA
16-MAY-17 13:57:48.368: Completed 2 PROCACT_SCHEMA objects in 1 seconds
16-MAY-17 13:57:48.373: Processing object type DATABASE_EXPORT/AUDIT
16-MAY-17 13:57:48.499: Completed 29 AUDIT objects in 0 seconds
16-MAY-17 13:57:48.504: Processing object type DATABASE_EXPORT/POST_SYSTEM_IMPCALLOUT/MARKER
16-MAY-17 13:57:49.501: Completed 1 MARKER objects in 1 seconds
16-MAY-17 13:57:49.552: Completed 30 DATABASE_EXPORT/NORMAL_OPTIONS/TABLE_DATA objects in 0 seconds
16-MAY-17 13:57:49.558: Completed 5 DATABASE_EXPORT/NORMAL_OPTIONS/VIEWS_AS_TABLES/TABLE_DATA objects in 2348 seconds
16-MAY-17 13:57:49.567: Completed 57 DATABASE_EXPORT/SCHEMA/TABLE/TABLE_DATA objects in 2349 seconds
16-MAY-17 13:57:49.628: Job "SYSTEM"."SYS_IMPORT_TRANSPORTABLE_01" completed with 44 error(s) at Tue May 16 13:57:49 2017 elapsed 0 00:00:41

I silently ignore the errors here. Some additional EXCLUDE statements will make this run flawless. Main reason for the errors is simply that with a 11.2.0.4 source database not everything gets excluded internally what should be excluded.

Anyhow, Case 1 looks ok.

SQL> select tablespace_name, status from dba_tablespaces;

TABLESPACE_NAME 	       STATUS
------------------------------ ---------
SYSTEM			       ONLINE
SYSAUX			       ONLINE
UNDOTBS1		       ONLINE
TEMP			       ONLINE
USERS			       ONLINE

But there are some details which may cause trouble. Quick look into the log file:

16-MAY-17 13:57:15.553: ORA-39083: Object type USER:"MIKE1" failed to create with error:
ORA-00959: tablespace 'MIKE1' does not exist
Failing sql is:
 CREATE USER "MIKE1" IDENTIFIED BY VALUES 'S:67D1974017CA6517A6A9BA1655182FEA352800F1460501DCD29602A666B3;CF5B00ED3595B543' DEFAULT TABLESPACE "MIKE1" TEMPORARY TABLESPACE "TEMP"
16-MAY-17 13:57:15.553: ORA-39083: Object type USER:"MIKE2" failed to create with error:
ORA-00959: tablespace 'MIKE2' does not exist
Failing sql is:
 CREATE USER "MIKE2" IDENTIFIED BY VALUES 'S:8915BFF218BB5A49958F5C12F4ED161BBB9EC71A54E1FFA471F94002F8C2;335808EE482DFA17' DEFAULT TABLESPACE "MIKE2" TEMPORARY TABLESPACE "TEMP"

Sure, as tablespace MIKE1 does not exist, user MIKE1 who had the default tablespace MIKE1 can’t be created either. This is ok in my case. But I’d like to point out that you have to pay close attention to such errors.

And of course, the same applies to objects in this tablespace(s) as well:

16-MAY-17 13:57:44.958: Processing object type DATABASE_EXPORT/SCHEMA/TABLE/TABLE
16-MAY-17 13:57:45.068: ORA-39083: Object type TABLE:"MIKE1"."TEST1" failed to create with error:
ORA-00959: tablespace 'MIKE1' does not exist
Failing sql is:
CREATE TABLE "MIKE1"."TEST1" ("OBJ#" NUMBER NOT NULL ENABLE, "DATAOBJ#" NUMBER, "OWNER#" NUMBER NOT NULL ENABLE, "NAME" VARCHAR2(30 BYTE) NOT NULL ENABLE, "NAMESPACE" NUMBER NOT NULL ENABLE, "SUBNAME" VARCHAR2(30 BYTE), "TYPE#" NUMBER NOT NULL ENABLE, "CTIME" DATE NOT NULL ENABLE, "MTIME" DATE NOT NULL ENABLE, "STIME" DATE NOT NULL ENABLE, "STATUS" NUMBER NOT NULL ENABLE, "R

Be careful!

Case 2 – Run expdp but EXCLUDE some tablespaces during impdp

Parameter files look like this for exp.par:

directory=oradump
dumpfile=exp.dmp
logfile=exp.log
transportable=always
full=y
metrics=y
version=12
exclude=table_statistics,index_statistics

and for imp.par:

directory=oradump
dumpfile=exp.dmp
logfile=imp.log
metrics=y
logtime=all
exclude=tablespace:"IN ('MIKE1', 'MIKE2')"
transport_datafiles='/u02/oradata/DB12/users01.dbf

But the result unfortunately is different. While the expdp runs smoothly of course, the impdp fails:

$ impdp parfile=imp.par

Import: Release 12.2.0.1.0 - Production on Thu May 16 17:18:54 2017

Copyright (c) 1982, 2017, Oracle and/or its affiliates.  All rights reserved.

Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
ORA-39002: invalid operation
ORA-39352: Wrong number of TRANSPORT_DATAFILES specified: expected 3, received 1

Case 2 does not work.

Summary

You can EXCLUDE one or more tablespaces when doing a Full Transportable Export/Import but you have to be careful. My approach from above is simple and does not have any dependencies. Be aware thst the Full Transportable Export/Import will try to create the users and objects – and will fail of course if the tablespace is not part of the operatio

–Mike

Full Transportable Export/Import – PAR File Examples

Roy and I blogged about Full Transportable Export/Import in the past:

If you haven’t heard of this database feature, it allows you to migrate a full database by using Transportable Tablespaces as a base technology but letting Data Pump do all the manual steps for you in a one-command migration. And if needed, it works with RMAN Incremental Backups as well in order to decrease the downtime for copying larger databases. It works cross-platform, cross-Endianness – and as early as with a source version of Oracle Database 11.2.0.3 – but only towards Oracle Database 12c.

Often there are questions regarding the correct syntax for the parameter files. As I have to look it up from time to time as well I thought I’d share some example par files as there are two different approaches: With or without NETWORK_LINK.

With expdp/impdp – without NETWORK_LINK

expdp.par

directory=oradump
dumpfile=wspmst_ftex_exp.dmp
logfile=wspmst_ftex_exp.log
transportable=always
full=y
metrics=y
logtime=all
exclude=table_statistics,index_statistics

impdp.par

directory=oradump
dumpfile=wspmst_ftex_exp.dmp
logfile=wspmst_ftex_imp.log
metrics=y
logtime=all
TRANSPORT_DATAFILES='/oradata/wspmst/data/WSPMSTCON/3ABC7F153DB55A4DE0539ED0C80A102D/datafile/advsecmon.331.880913493'
TRANSPORT_DATAFILES='/oradata/wspmst/data/WSPMSTCON/3ABC7F153DB55A4DE0539ED0C80A102D/datafile/advsecmon.555.880923697'

Only impdp (no expdp) – using NETWORK_LINK

2 examples here – one dealing with an Oracle 11.2 source database, the other moving directly from Oracle 12c non-CDB into a pluggable database (PDB).

impdp1.par

impdp mike/passwd@v121
NETWORK_LINK=v112

FULL=Y
TRANSPORTABLE=ALWAYS
VERSION=12
METRICS=Y
exclude=table_statistics,index_statistics

LOGTIME=ALL
 LOGFILE=ftex_dir:v112fullimp.log
TRANSPORT_DATAFILES='/oracle/DQ1/sapdata50/ts1.dbf'
TRANSPORT_DATAFILES='/oracle/DQ1/sapdata50/ts2.dbf'

impdp2.par

impdp system/oracle@pdb2
network_link=sourcedb
full=y
transportable=always
metrics=y
exclude=table_statistics,index_statistics
directory=mydir logfile=pdb2.log
transport_datafiles='/u02/oradata/CDB2/pdb2/users01.dbf'
transport_datafiles='/u02/oradata/CDB2/pdb2/users02.dbf'
transport_datafiles='/u02/oradata/CDB2/pdb2/users03.dbf'

Please note:

  • The VERSION=12 option must be used only when an Oracle 11.2 database is the source as in this case Data Pump on the 11.2 side must be triggered to access this 12c feature and create an export in a form the 12c Data Pump can understand.
  • There’s no expdp necessary when using Data Pump over a database link (NETWORK_LINK). But in this case you will need the keywords FULL=Y and TRANSPORTABLE=ALWAYS as export parameters as the export portion of Data Pump on the source side will be triggered underneath the covers.

–Mike

Transportable Tablespaces – Characters Sets – Same same but different?

All credits go to Don Wolf, an Oracle Advanced Customer Support engineer from Ohio as he dug out this information 🙂 Thanks Don!

Do database character sets have to match EXACTLY for Transportable Tablespaces?

That sounds like a simple question. When you look into our big slide deck the answer will be a straight “Yes”. No doubts. Regardless if you would like to do Transportable Tablespaces or Full Transportable Export/Import your sources and your target’s database character sets must be equal. Otherwise Data Pump won’t allow you to process the meta data import.

But Don was wondering about slightly differing information in MOS notes and the documentation.
And asked me if I can clarify things. I couldn’t.

  • MOS Note:1454872.1
    Transportable Tablespace (TTS) Restrictions and Limitations:
    Details, Reference, and Version Where Applicable

    tells you:

  •  And the above documentation link then tells you:
    • The source and the destination databases must use compatible database character sets. That is, one of the following must be true:
      • The database character sets of the source and the target databases are the same.
      • The source database character set is a strict (binary) subset of the target database character set, and the following three conditions are true:
        • The source database is in version 10.1.0.3 or higher.
        • The tablespaces to be transported contain no table columns with character length semantics or the maximum character width is the same in both the source and target database character sets.
        • The tablespaces to be transported contain no columns with the CLOB data type, or the source and the target database character sets are both single-byte or both multibyte.
      • The source database character set is a strict (binary) subset of the target database character set, and the following two conditions are true:
        • The source database is in a version lower than 10.1.0.3.
        • The maximum character width is the same in the source and target database character sets.
  • And furthermore from “Choosing a Character Set” section of Oracle 12.1  Database Globalization Support Guide:
    • Oracle
      Database does not maintain a list of all subset-superset pairs but it
      does maintain a list of binary subset-superset pairs that it recognizes
      in various situations such as checking compatibility of a transportable
      tablespace or a pluggable database. Table A-11 and Table A-12 list the
      binary subset-superset pairs recognized by Oracle Database.
    • In those tables the only binary subset-superset pairs involving AL32UTF8 are:
      • UTF8/AL32UTF8
      • US7ASCII/AL32UTF8
  • This is not 100% congruent to the information provided in
    MOS Note 371556.1 – How to Migrate to different Endian Platform Using
    Transportable Tablespaces With RMAN

    saying:
    The source and target database must use the same character set and national character set.

What is correct, what’s not?

First of all the wording of “compatible character sets” seems to be gotten introduced with Oracle Database 11.2.

In fact the scope for the target system has become broader in Oracle Database 11.2.  These rule here are correct as soon as your target database is an Oracle Database 11.2 or newer database release.

  • The source and the destination databases must use compatible database character sets. That is, one of the following must be true:
    • The database character sets of the source and the target databases are the same.
    • The source database character set is a strict (binary) subset of the target database character set, and the following three conditions are true:
      • The source database is in version 10.1.0.3 or higher.
      • The tablespaces to be transported contain no table columns with character length semantics or the maximum character width is the same in both the source and target database character sets.
      • The tablespaces to be transported contain no columns with the CLOB data type, or the source and the target database character sets are both single-byte or both multibyte.
    • The source database character set is a strict (binary) subset of the target database character set, and the following two conditions are true:
      • The source database is in a version lower than 10.1.0.3.
      • The maximum character width is the same in the source and target database character sets.

–Mike

Full Transportable Export/Import White Paper

One of the really cool and helpful features in Oracle Database 12c is called Full Transportable Export/Import. It combines the basics of transportable tablespaces – of course cross-platform, cross-endianess, cross-version – with Data Pump taking care on all the stuff not stored in tables and indexes, such as views, synonyms, trigger, packages etc. And you can even reduce downtime by combining the feature with incrementally converted RMAN backups.

And the best thing: this will work with an Oracle Database 11.2.0.3/4 to Oracle Database 12c – so you don’t have to be on Oracle Database 12c in order to leverage from that cool new feature.

See the brand new White Paper about Full Transportable Export/Import here:
http://www.oracle.com/technetwork/database/enterprise-edition/full-transportable-wp-12c-1973971.pdf

-Mike