[20150707]数据泵造成的数据损失.txt
--参看链接,重复测试http://yangtingkun.net/?p=652
SCOTT@test> @ver1
PORT_STRING VERSION BANNER
------------------------------ -------------- --------------------------------------------------------------------------------
x86_64/Linux 2.4.xx 11.2.0.3.0 Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
CREATE TABLE T_PART PARTITION BY RANGE (CREATED)
(PARTITION P1 VALUES LESS THAN (TO_DATE('2012-1-1', 'YYYY-MM-DD')),
PARTITION P2 VALUES LESS THAN (TO_DATE('2012-2-1', 'YYYY-MM-DD')),
PARTITION P3 VALUES LESS THAN (TO_DATE('2012-3-1', 'YYYY-MM-DD')),
PARTITION P4 VALUES LESS THAN (TO_DATE('2012-4-1', 'YYYY-MM-DD')),
PARTITION PMAX VALUES LESS THAN (MAXVALUE))
AS SELECT * FROM DBA_OBJECTS;
SCOTT@test> select count(*) from t_part partition (p4);
COUNT(*)
----------
31
SCOTT@test> select count(*) from t_part partition (p3);
COUNT(*)
----------
9
SCOTT@test> select count(*) from t_part partition (pmax);
COUNT(*)
----------
10005
SCOTT@test> select count(*) from t_part partition (p1);
COUNT(*)
----------
67590
SCOTT@test> select count(*) from t_part partition (p2);
COUNT(*)
----------
115
$ expdp scott/btbtms directory=DATA_PUMP_DIR dumpfile=t_part.dmp logfile=t_part.log tables=t_part:p3,t_part:p4
Export: Release 11.2.0.3.0 - Production on Tue Jul 7 09:00:25 2015
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
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 "SCOTT"."SYS_EXPORT_TABLE_01": scott/a****** directory=DATA_PUMP_DIR dumpfile=t_part.dmp logfile=t_part.log tables=t_part:p3,t_part:p4
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 16 MB
Processing object type TABLE_EXPORT/TABLE/TABLE
. . exported "SCOTT"."T_PART":"P3" 11.49 KB 9 rows
. . exported "SCOTT"."T_PART":"P4" 13.89 KB 31 rows
Master table "SCOTT"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SCOTT.SYS_EXPORT_TABLE_01 is:
/u01/app/oracle11g/admin/test/dpdump/t_part.dmp
Job "SCOTT"."SYS_EXPORT_TABLE_01" successfully completed at 09:00:50
$ impdp scott/btbtms directory=DATA_PUMP_DIR dumpfile=t_part.dmp logfile=t_part_imp.log tables=t_part:p3 table_exists_action=replace
Import: Release 11.2.0.3.0 - Production on Tue Jul 7 09:02:15 2015
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
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 "SCOTT"."SYS_IMPORT_TABLE_01" successfully loaded/unloaded
Starting "SCOTT"."SYS_IMPORT_TABLE_01": scott/a******* directory=DATA_PUMP_DIR dumpfile=t_part.dmp logfile=t_part_imp.log tables=t_part:p3 table_exists_action=replace
Processing object type TABLE_EXPORT/TABLE/TABLE
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
. . imported "SCOTT"."T_PART":"P3" 11.49 KB 9 rows
Job "SCOTT"."SYS_IMPORT_TABLE_01" successfully completed at 09:02:20
虽然导入的时候仅指定了一个分区,但是Oracle并不会对这一个分区执行TRUNCATE操作,而是将整个表DROP掉,然后利用数据泵中的源数
据重建。
SCOTT@test> select count(*) from t_part partition (p1);
COUNT(*)
----------
0
SCOTT@test> select count(*) from t_part partition (p2);
COUNT(*)
----------
0
SCOTT@test> select count(*) from t_part partition (p3);
COUNT(*)
----------
9
SCOTT@test> select count(*) from t_part partition (p4);
COUNT(*)
----------
0
SCOTT@test> select count(*) from t_part partition (pmax);
COUNT(*)
----------
0
这个表中只有导入的分区记录存在,原则上impdp对应的数据泵导出文件中的记录也都是可以恢复的,但是表中其他的分区数据则完全丢
失。
而且Oracle在删除的时候还使用PURGE选项,使得分区表在删除的时候并没有被放到回收站中,而是直接从数据库中被清除。从这一点上
讲,Oracle应该去掉PURGE语句,或者至少给出一个选项,毕竟DROP TABLE对于系统来说有风险的。
--比较正确的做法是:
SCOTT@test> delete from t_part partition(p3);
9 rows deleted.
SCOTT@test> commit ;
Commit complete.
$ impdp scott/btbtms directory=DATA_PUMP_DIR dumpfile=t_part.dmp logfile=t_part_imp.log tables=t_part:p3 table_exists_action=append
Import: Release 11.2.0.3.0 - Production on Tue Jul 7 09:15:25 2015
Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved.
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 "SCOTT"."SYS_IMPORT_TABLE_01" successfully loaded/unloaded
Starting "SCOTT"."SYS_IMPORT_TABLE_01": scott/a******* directory=DATA_PUMP_DIR dumpfile=t_part.dmp logfile=t_part_imp.log tables=t_part:p3 table_exists_action=append
Processing object type TABLE_EXPORT/TABLE/TABLE
Table "SCOTT"."T_PART" exists. Data will be appended to existing table but all dependent metadata will be skipped due to table_exists_action of append
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
. . imported "SCOTT"."T_PART":"P3" 11.49 KB 9 rows
Job "SCOTT"."SYS_IMPORT_TABLE_01" successfully completed at 09:15:31
SCOTT@test> select count(*) from t_part partition (p4);
COUNT(*)
----------
31
SCOTT@test> select count(*) from t_part partition (p1);
COUNT(*)
----------
67590
SCOTT@test> select count(*) from t_part partition (p2);
COUNT(*)
----------
115
SCOTT@test> select count(*) from t_part partition (p3);
COUNT(*)
----------
9
SCOTT@test> select count(*) from t_part partition (pmax);
COUNT(*)
----------
10005