What happens upon Data Pump Export if tables are being exported that have a Data Redaction Policy? I got that question several times in class, which is why I put the answer here , so I can refer to it subsequently. Might also be of interest to the Oracle Community 🙂
SYS@orcl > BEGIN DBMS_REDACT.ADD_POLICY (object_schema => 'SCOTT', object_name => 'EMP', policy_name => 'EMPSAL_POLICY', column_name => 'SAL', function_type => DBMS_REDACT.FULL, expression => '1=1'); END; / PL/SQL procedure successfully completed. SYS@orcl > connect scott/tiger Connected. SCOTT@orcl > select ename,sal from emp; ENAME SAL ---------- ---------- SMITH 0 ALLEN 0 WARD 0 JONES 0 MARTIN 0 BLAKE 0 CLARK 0 SCOTT 0 KING 0 TURNER 0 ADAMS 0 JAMES 0 FORD 0 MILLER 0 14 rows selected.
Scott doesn’t see the values of the SAL column because of the Data Redaction Policy. SYS is not subject to that policy, because SYS has the privilege EXEMPT REDACTION POLICY:
SYS@orcl > select ename,sal from scott.emp; ENAME SAL ---------- ---------- SMITH 800 ALLEN 1600 WARD 1250 JONES 2975 MARTIN 1250 BLAKE 2850 CLARK 2450 SCOTT 9000 KING 5000 TURNER 1500 ADAMS 1100 JAMES 950 FORD 9000 MILLER 1300 14 rows selected.
If Data Pump Export is done as a user who owns that privilege, the table is just exported with all its content, regardless of the policy:
SYS@orcl > create directory dpdir as '/home/oracle/'; [oracle@uhesse ~]$ expdp tables=scott.emp directory=DPDIR Export: Release 12.1.0.2.0 - Production on Fri Aug 5 08:56:51 2016 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Username: / as sysdba Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics, Real Application Testing and Unified Auditing options Starting "SYS"."SYS_EXPORT_TABLE_01": /******** AS SYSDBA tables=scott.emp directory=DPDIR Estimate in progress using BLOCKS method... Processing object type TABLE_EXPORT/TABLE/TABLE_DATA Total estimation using BLOCKS method: 64 KB Processing object type TABLE_EXPORT/TABLE/TABLE Processing object type TABLE_EXPORT/TABLE/RADM_POLICY Processing object type TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER . . exported "SCOTT"."EMP" 8.781 KB 14 rows Master table "SYS"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded ****************************************************************************** Dump file set for SYS.SYS_EXPORT_TABLE_01 is: /home/oracle/expdat.dmp Job "SYS"."SYS_EXPORT_TABLE_01" successfully completed at Fri Aug 5 08:57:10 2016 elapsed 0 00:00:15
If Scott tries to export the table, that raises an error message:
SYS@orcl > grant read,write on directory dpdir to scott;
Grant succeeded.
[oracle@uhesse ~]$ expdp scott/tiger tables=scott.emp directory=DPDIR
Export: Release 12.1.0.2.0 - Production on Fri Aug 5 08:55:10 2016
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, Real Application Testing
and Unified Auditing options
Starting "SCOTT"."SYS_EXPORT_TABLE_01": scott/******** tables=scott.emp directory=DPDIR
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 64 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/GRANT/OWNER_GRANT/OBJECT_GRANT
Processing object type TABLE_EXPORT/TABLE/INDEX/INDEX
Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/CONSTRAINT
Processing object type TABLE_EXPORT/TABLE/INDEX/STATISTICS/INDEX_STATISTICS
Processing object type TABLE_EXPORT/TABLE/CONSTRAINT/REF_CONSTRAINT
Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
ORA-31693: Table data object "SCOTT"."EMP" failed to load/unload and is being skipped due to error:
ORA-28081: Insufficient privileges - the command references a redacted object.
Master table "SCOTT"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SCOTT.SYS_EXPORT_TABLE_01 is:
/home/oracle/expdat.dmp
Job "SCOTT"."SYS_EXPORT_TABLE_01" completed with 1 error(s) at Fri Aug 5 08:55:28 2016 elapsed 0 00:00:16
Taken from the 12c New Features class that I delivered this week in Hinckley. As always: Don’t believe it, test it 🙂
#1 von liviu am August 5, 2016 - 15:19
Cool ! Uwe will you deliver any training in Bucharest soon ? I am looking forward to attend it !
#2 von Arpit Agrawal am August 6, 2016 - 07:24
good to know about it. Thanks