Here I’m go to demonstrate How do we recover truncate table using RMAN tablespace point in time recovery.
I hope This post may very user friendly for you without confusion 🙂
Step 1: Create tablespace and allocate one user for this tablespace
SQL> create tablespace rmantbs datafile 'c:\temp\rmnatbs01.dbf' size 100m;
Tablespace created.
SQL> create user rmantbs identified by rmantbs default tablespace rmantbs;
User created.
SQL> grant connect,resource to rmantbs;
Grant succeeded.
SQL> grant read,write on directory data_pump_dir to rmantbs;
Grant succeeded.
Step 2: Create another one tablespace and allocated another new user which one checking data lost will happen or not after TBPITR recovery done.
SQL> create tablespace rmantest datafile 'c:\temp\rmantest01.dbf' size 50m;
Tablespace created.
SQL> create user rmantest identified by rmantest default tablespace rmantest;
User created.
SQL> grant connect,resource to rmantest;
Grant succeeded.
Step 3: Create two table and insert few rows
SQL> set time on
21:12:02 SQL> conn rmantbs/rmantbs
Connected.
21:12:25 SQL> create table employee(empno number,empname varchar2(20));
Table created.
21:13:20 SQL> insert into employee values(001,'azar');
1 row created.
21:13:36 SQL> insert into employee values(002,'jabar');
1 row created.
21:13:45 SQL> insert into employee values(003,'kareem');
1 row created.
21:13:54 SQL> insert into employee values(004,'ajmal');
1 row created.
21:14:08 SQL> commit;
Commit complete.
21:14:11 SQL> create table empcity(cityname varchar2(20));
Table created.
21:14:41 SQL> insert into empcity values('riyadh');
1 row created.
21:14:53 SQL> commit;
Commit complete.
Step 4: create anothe one table for rmantest user which allocated rmantest tablespace.
:55 SQL> conn rmantest/rmantest
Connected.
21:15:01 SQL> create table a(empno number);
Table created.
21:15:14 SQL> insert into a values(001);
1 row created.
21:15:24 SQL> insert into a values(002);
1 row created.
21:15:29 SQL> insert into a values(003);
1 row created.
21:15:39 SQL> insert into a values(004);
1 row created.
21:15:42 SQL> commit;
Commit complete.
Step 5: Switch logfile
21:15:44 SQL> conn / as sysdba
Connected.
21:15:53 SQL> alter system switch logfile;
System altered.
Step 6: Backup database with archivelog
RMAN> backup database plus archivelog;
Starting backup at 25-APR-11
current log archived
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=134 device type=DISK
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=2 RECID=1 STAMP=749251241
input archived log thread=1 sequence=3 RECID=2 STAMP=749332191
input archived log thread=1 sequence=4 RECID=3 STAMP=749333774
input archived log thread=1 sequence=5 RECID=4 STAMP=749333841
input archived log thread=1 sequence=6 RECID=5 STAMP=749333984
input archived log thread=1 sequence=7 RECID=6 STAMP=749338753
input archived log thread=1 sequence=8 RECID=7 STAMP=749342576
input archived log thread=1 sequence=9 RECID=8 STAMP=749342688
input archived log thread=1 sequence=10 RECID=9 STAMP=749417043
input archived log thread=1 sequence=11 RECID=10 STAMP=749423783
input archived log thread=1 sequence=12 RECID=11 STAMP=749423884
channel ORA_DISK_1: starting piece 1 at 25-APR-11
channel ORA_DISK_1: finished piece 1 at 25-APR-11
piece handle=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\BACKUPSET\2011_04_25\O1_MF_
ANNNN_TAG20110425T211805_6VCGPYCN_.BKP tag=TAG20110425T211805 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
Finished backup at 25-APR-11
Starting backup at 25-APR-11
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00001 name=C:\APP\AZAR\ORADATA\RMANTBS\SYSTEM01.DBF
input datafile file number=00002 name=C:\APP\AZAR\ORADATA\RMANTBS\SYSAUX01.DBF
input datafile file number=00005 name=C:\TEMP\RMNATBS01.DBF
input datafile file number=00006 name=C:\TEMP\RMANTEST01.DBF
input datafile file number=00003 name=C:\APP\AZAR\ORADATA\RMANTBS\UNDOTBS01.DBF
input datafile file number=00004 name=C:\APP\AZAR\ORADATA\RMANTBS\USERS01.DBF
channel ORA_DISK_1: starting piece 1 at 25-APR-11
channel ORA_DISK_1: finished piece 1 at 25-APR-11
piece handle=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\BACKUPSET\2011_04_25\O1_MF_
NNNDF_TAG20110425T211821_6VCGQGL8_.BKP tag=TAG20110425T211821 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:01:55
Finished backup at 25-APR-11
Starting backup at 25-APR-11
current log archived
using channel ORA_DISK_1
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=13 RECID=12 STAMP=749424018
channel ORA_DISK_1: starting piece 1 at 25-APR-11
channel ORA_DISK_1: finished piece 1 at 25-APR-11
piece handle=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\BACKUPSET\2011_04_25\O1_MF_
ANNNN_TAG20110425T212018_6VCGV2GZ_.BKP tag=TAG20110425T212018 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 25-APR-11
Starting Control File and SPFILE Autobackup at 25-APR-11
piece handle=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\AUTOBACKUP\2011_04_25\O1_MF
_S_749424019_6VCGV4KX_.BKP comment=NONE
Finished Control File and SPFILE Autobackup at 25-APR-11
RMAN>
Step 7: Note Current Timestamp before truncate table
21:16:23 SQL> select current_timestamp from dual;
CURRENT_TIMESTAMP
---------------------------------------------------------------------------
25-APR-11 09.21.30.293000 PM +03:00 21:21:30 SQL> conn rmantbs/rmantbs
Connected.
21:21:49 SQL> select * from employee;
EMPNO EMPNAME
---------- --------------------
1 azar
2 jabar
3 kareem
4 ajmal
21:22:13 SQL> truncate table employee;
Table truncated.
Step 8: Insert some few rows for another one table which is usefull for whether data loss or not and also How do we preserve these data.
21:25:16 SQL> insert into empcity values('chennai');
1 row created.
21:27:14 SQL> insert into empcity values('trichy');
1 row created.
21:27:22 SQL> insert into empcity values('dammam');
1 row created.
21:27:33 SQL> conn rmantest/rmantest
Connected.
21:27:44 SQL> insert into a values(005);
1 row created.
21:27:53 SQL> commit;
Commit complete.
Step 9: Before you done tbpitr, you must check Determine and Resolved Dependencies
21:27:59 SQL> conn / as sysdba
Connected.
21:35:14 SQL> SELECT * FROM sys.ts_pitr_check WHERE(ts1_name = 'RMANTBS' AND ts2
_name != 'RMANTBS') OR (ts1_name != 'RMANTBS' AND ts2_name = 'RMANTBS');
no rows selected
Step 10 : Determine Which Objects Will Not Be Recovered
For objects in tablespaces involved with the TSPITR, you’ll lose any transactions that were
created prior to the point to which you restore. If you need to preserve objects created after
the time to which you are going to restore, then you’ll need to use the Datapump or Export utility to save them.
After you have performed TSPITR, then you can import these objects.
21:36:47 SQL> SELECT owner, name, tablespace_name FROM ts_pitr_objects_to_be_dro
pped WHERE tablespace_name ='RMANTBS' AND creation_time > to_date('25-APR-11 09.
21.30','DD-MON-RRRR HH24:MI:SS');
OWNER NAME
------------------------------ ------------------------------
TABLESPACE_NAME
------------------------------
RMANTBS EMPLOYEE
RMANTBS
RMANTBS EMPCITY
RMANTBS
More details about See metalink ID TSPITR:How to check dependency of the objects and identifying objects that will be lost after TSPITR [ID 304308.1]
Step 11: Export the above two tables data for safe purpose.But Here Employee table not need, only EMPCITY table enough for export, However I exported two tables
C:\Users\Azar>expdp rmantbs/rmantbs directory=data_pump_dir dumpfile=datatbs.dmp
logfile=datatbs.log tables=employee,empcity
Export: Release 11.2.0.1.0 - Production on Mon Apr 25 21:38:33 2011
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit
Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Starting "RMANTBS"."SYS_EXPORT_TABLE_01": rmantbs/******** directory=data_pump_
dir dumpfile=datatbs.dmp logfile=datatbs.log tables=employee,empcity
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
. . exported "RMANTBS"."EMPCITY" 5.062 KB 4 rows
. . exported "RMANTBS"."EMPLOYEE" 0 KB 0 rows
Master table "RMANTBS"."SYS_EXPORT_TABLE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for RMANTBS.SYS_EXPORT_TABLE_01 is:
C:\APP\AZAR\ADMIN\RMANTBS\DPDUMP\DATATBS.DMP
Job "RMANTBS"."SYS_EXPORT_TABLE_01" successfully completed at 21:38:53
Step 12: Recover Truncate table using TBPITR
RMAN> recover tablespace RMANTBS until time "to_date('25-APR-11 21:21:30','DD-MO
N-RRRR HH24:MI:SS')" auxiliary destination 'C:\TEMP\auxxtest';
Starting recover at 25-APR-11
using channel ORA_DISK_1
RMAN-05026: WARNING: presuming following set of tablespaces applies to specified
point-in-time
List of tablespaces expected to have UNDO segments
Tablespace SYSTEM
Tablespace UNDOTBS1
Creating automatic instance, with SID='mbfF'
initialization parameters used for automatic instance:
db_name=RMANTBS
db_unique_name=mbfF_tspitr_RMANTBS
compatible=11.2.0.0.0
db_block_size=8192
db_files=200
sga_target=280M
processes=50
db_create_file_dest=C:\TEMP\auxxtest
log_archive_dest_1='location=C:\TEMP\auxxtest'
#No auxiliary parameter file used
starting up automatic instance RMANTBS
Oracle instance started
Total System Global Area 292278272 bytes
Fixed Size 2175128 bytes
Variable Size 100667240 bytes
Database Buffers 184549376 bytes
Redo Buffers 4886528 bytes
Automatic instance created
Running TRANSPORT_SET_CHECK on recovery set tablespaces
contents of Memory Script:
{
# set requested point in time
set until time "to_date('25-APR-11 21:21:30','DD-MON-RRRR HH24:MI:SS')";
# restore the controlfile
restore clone controlfile;
# mount the controlfile
sql clone 'alter database mount clone database';
# archive current online log
sql 'alter system archive log current';
# avoid unnecessary autobackups for structural changes during TSPITR
sql 'begin dbms_backup_restore.AutoBackupFlag(FALSE); end;';
}
executing Memory Script
executing command: SET until clause
Starting restore at 25-APR-11
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=60 device type=DISK
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: restoring control file
channel ORA_AUX_DISK_1: reading from backup piece C:\APP\AZAR\FLASH_RECOVERY_ARE
A\RMANTBS\AUTOBACKUP\2011_04_25\O1_MF_S_749424019_6VCGV4KX_.BKP
channel ORA_AUX_DISK_1: piece handle=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\AUT
OBACKUP\2011_04_25\O1_MF_S_749424019_6VCGV4KX_.BKP tag=TAG20110425T212019
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:03
output file name=C:\TEMP\AUXXTEST\RMANTBS\CONTROLFILE\O1_MF_6VCJBORG_.CTL
Finished restore at 25-APR-11
sql statement: alter database mount clone database
sql statement: alter system archive log current
sql statement: begin dbms_backup_restore.AutoBackupFlag(FALSE); end;
contents of Memory Script:
{
# set requested point in time
set until time "to_date('25-APR-11 21:21:30','DD-MON-RRRR HH24:MI:SS')";
plsql <<<-- tspitr_2
declare
sqlstatement varchar2(512);
offline_not_needed exception;
pragma exception_init(offline_not_needed, -01539);
begin
sqlstatement := 'alter tablespace '|| 'RMANTBS' ||' offline immediate';
krmicd.writeMsg(6162, sqlstatement);
krmicd.execSql(sqlstatement);
exception
when offline_not_needed then
null;
end; >>>;
# set destinations for recovery set and auxiliary set datafiles
set newname for clone datafile 1 to new;
set newname for clone datafile 3 to new;
set newname for clone datafile 2 to new;
set newname for clone tempfile 1 to new;
set newname for datafile 5 to
"C:\TEMP\RMNATBS01.DBF";
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 1, 3, 2, 5;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
sql statement: alter tablespace RMANTBS offline immediate
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
renamed tempfile 1 to C:\TEMP\AUXXTEST\RMANTBS\DATAFILE\O1_MF_TEMP_%U_.TMP in co
ntrol file
Starting restore at 25-APR-11
using channel ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_1: restoring datafile 00001 to C:\TEMP\AUXXTEST\RMANTBS\DAT
AFILE\O1_MF_SYSTEM_%U_.DBF
channel ORA_AUX_DISK_1: restoring datafile 00003 to C:\TEMP\AUXXTEST\RMANTBS\DAT
AFILE\O1_MF_UNDOTBS1_%U_.DBF
channel ORA_AUX_DISK_1: restoring datafile 00002 to C:\TEMP\AUXXTEST\RMANTBS\DAT
AFILE\O1_MF_SYSAUX_%U_.DBF
channel ORA_AUX_DISK_1: restoring datafile 00005 to C:\TEMP\RMNATBS01.DBF
channel ORA_AUX_DISK_1: reading from backup piece C:\APP\AZAR\FLASH_RECOVERY_ARE
A\RMANTBS\BACKUPSET\2011_04_25\O1_MF_NNNDF_TAG20110425T211821_6VCGQGL8_.BKP
channel ORA_AUX_DISK_1: piece handle=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\BAC
KUPSET\2011_04_25\O1_MF_NNNDF_TAG20110425T211821_6VCGQGL8_.BKP tag=TAG20110425T2
11821
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:01:26
Finished restore at 25-APR-11
datafile 1 switched to datafile copy
input datafile copy RECID=4 STAMP=749425659 file name=C:\TEMP\AUXXTEST\RMANTBS\D
ATAFILE\O1_MF_SYSTEM_6VCJCP1B_.DBF
datafile 3 switched to datafile copy
input datafile copy RECID=5 STAMP=749425659 file name=C:\TEMP\AUXXTEST\RMANTBS\D
ATAFILE\O1_MF_UNDOTBS1_6VCJCP58_.DBF
datafile 2 switched to datafile copy
input datafile copy RECID=6 STAMP=749425659 file name=C:\TEMP\AUXXTEST\RMANTBS\D
ATAFILE\O1_MF_SYSAUX_6VCJCP53_.DBF
contents of Memory Script:
{
# set requested point in time
set until time "to_date('25-APR-11 21:21:30','DD-MON-RRRR HH24:MI:SS')";
# online the datafiles restored or switched
sql clone "alter database datafile 1 online";
sql clone "alter database datafile 3 online";
sql clone "alter database datafile 2 online";
sql clone "alter database datafile 5 online";
# recover and open resetlogs
recover clone database tablespace "RMANTBS", "SYSTEM", "UNDOTBS1", "SYSAUX" del
ete archivelog;
alter clone database open resetlogs;
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 1 online
sql statement: alter database datafile 3 online
sql statement: alter database datafile 2 online
sql statement: alter database datafile 5 online
Starting recover at 25-APR-11
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 13 is already on disk as file C:\APP\AZA
R\FLASH_RECOVERY_AREA\RMANTBS\ARCHIVELOG\2011_04_25\O1_MF_1_13_6VCGV25P_.ARC
archived log for thread 1 with sequence 14 is already on disk as file C:\APP\AZA
R\FLASH_RECOVERY_AREA\RMANTBS\ARCHIVELOG\2011_04_25\O1_MF_1_14_6VCJBXKV_.ARC
archived log file name=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\ARCHIVELOG\2011_0
4_25\O1_MF_1_13_6VCGV25P_.ARC thread=1 sequence=13
archived log file name=C:\APP\AZAR\FLASH_RECOVERY_AREA\RMANTBS\ARCHIVELOG\2011_0
4_25\O1_MF_1_14_6VCJBXKV_.ARC thread=1 sequence=14
media recovery complete, elapsed time: 00:00:01
Finished recover at 25-APR-11
database opened
contents of Memory Script:
{
# make read only the tablespace that will be exported
sql clone 'alter tablespace RMANTBS read only';
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
C:\TEMP\auxxtest''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
C:\TEMP\auxxtest''";
}
executing Memory Script
sql statement: alter tablespace RMANTBS read only
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''C:\TEMP\auxx
test''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''C:\TEMP\auxx
test''
Performing export of metadata...
EXPDP> Starting "SYS"."TSPITR_EXP_mbfF":
EXPDP> Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK
EXPDP> Processing object type TRANSPORTABLE_EXPORT/TABLE
EXPDP> Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK
EXPDP> Master table "SYS"."TSPITR_EXP_mbfF" successfully loaded/unloaded
EXPDP> **********************************************************************
********
EXPDP> Dump file set for SYS.TSPITR_EXP_mbfF is:
EXPDP> C:\TEMP\AUXXTEST\TSPITR_MBFF_12962.DMP
EXPDP> **********************************************************************
********
EXPDP> Datafiles required for transportable tablespace RMANTBS:
EXPDP> C:\TEMP\RMNATBS01.DBF
EXPDP> Job "SYS"."TSPITR_EXP_mbfF" successfully completed at 21:49:42
Export completed
contents of Memory Script:
{
# shutdown clone before import
shutdown clone immediate
# drop target tablespaces before importing them back
sql 'drop tablespace RMANTBS including contents keep datafiles';
}
executing Memory Script
database closed
database dismounted
Oracle instance shut down
sql statement: drop tablespace RMANTBS including contents keep datafiles
Performing import of metadata...
IMPDP> Master table "SYS"."TSPITR_IMP_mbfF" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_mbfF":
IMPDP> Processing object type TRANSPORTABLE_EXPORT/PLUGTS_BLK
IMPDP> Processing object type TRANSPORTABLE_EXPORT/TABLE
IMPDP> Processing object type TRANSPORTABLE_EXPORT/POST_INSTANCE/PLUGTS_BLK
IMPDP> Job "SYS"."TSPITR_IMP_mbfF" successfully completed at 21:50:03
Import completed
contents of Memory Script:
{
# make read write and offline the imported tablespaces
sql 'alter tablespace RMANTBS read write';
sql 'alter tablespace RMANTBS offline';
# enable autobackups after TSPITR is finished
sql 'begin dbms_backup_restore.AutoBackupFlag(TRUE); end;';
}
executing Memory Script
sql statement: alter tablespace RMANTBS read write
sql statement: alter tablespace RMANTBS offline
sql statement: begin dbms_backup_restore.AutoBackupFlag(TRUE); end;
Removing automatic instance
Automatic instance removed
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\DATAFILE\O1_MF_TEMP_6VCJGXY6_.T
MP deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\ONLINELOG\O1_MF_3_6VCJGTWP_.LOG
deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\ONLINELOG\O1_MF_2_6VCJGST5_.LOG
deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\ONLINELOG\O1_MF_1_6VCJGKK2_.LOG
deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\DATAFILE\O1_MF_SYSAUX_6VCJCP53_
.DBF deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\DATAFILE\O1_MF_UNDOTBS1_6VCJCP5
8_.DBF deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\DATAFILE\O1_MF_SYSTEM_6VCJCP1B_
.DBF deleted
auxiliary instance file C:\TEMP\AUXXTEST\RMANTBS\CONTROLFILE\O1_MF_6VCJBORG_.CTL
deleted
Finished recover at 25-APR-11
RMAN>
Step 13 : After done it, Backup tablespace
RMAN>backup tablespace rmantbs;
Step 14: tablespace online
21:54:34 SQL> alter tablespace rmantbs online;
Tablespace altered.
Step 15: Check whether truncate table recovered or not
:44 SQL> conn rmantbs/rmantbs;
Connected.
21:54:52 SQL> select * from employee;
EMPNO EMPNAME
---------- --------------------
1 azar
2 jabar
3 kareem
4 ajmal
Now It was recovered.
Step 16: Now I’m going to check another table whether inserted data availble after done TBPITR time
21:55:01 SQL> select * from empcity;
CITYNAME
--------------------
riyadh
Not availble, So in this case I’m going to import this table data from dumpfile , this dumpfile taken before I do TBPITR
Step 17: Import table
C:\Users\Azar>impdp rmantbs/rmantbs directory=data_pump_dir dumpfile=datatbs.dmp
logfile=datatbsimp.log tables=empcity table_exists_action=append
Import: Release 11.2.0.1.0 - Production on Mon Apr 25 21:58:40 2011
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit
Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Master table "RMANTBS"."SYS_IMPORT_TABLE_01" successfully loaded/unloaded
Starting "RMANTBS"."SYS_IMPORT_TABLE_01": rmantbs/******** directory=data_pump_
dir dumpfile=datatbs.dmp logfile=datatbsimp.log tables=empcity table_exists_acti
on=append
Processing object type TABLE_EXPORT/TABLE/TABLE
ORA-39152: Table "RMANTBS"."EMPCITY" exists. Data will be appended to existing t
able but all dependent metadata will be skipped due to table_exists_action of ap
pend
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
. . imported "RMANTBS"."EMPCITY" 5.062 KB 4 rows
Job "RMANTBS"."SYS_IMPORT_TABLE_01" completed with 1 error(s) at 21:58:42
21:55:09 SQL> conn rmantest/rmantest;
Connected.
21:55:28 SQL> select * from a;
EMPNO
----------
1
2
3
4
5
Step 18: And also I was checked , the other tablespace allocate table data consistent, Yes.
21:55:33 SQL> conn rmantbs/rmantbs;
Connected.
21:59:03 SQL> select * from empcity;
CITYNAME
--------------------
riyadh
riyadh
chennai
trichy
dammam
21:59:05 SQL>
Now Successfully Done It RMAN tablespace Point in time recovery.