To do that firstly I will create new tablespace then will create new user and make default tablespace to new user and the last I will create new table with some rows on mentioned tablespace.
SQL> create tablespace rec_tbs datafile '/u01/app/oracle/oradata/ulfetdb/rec_tbsp01.dbf' size 50m;
Tablespace created.
User created.
SQL> alter user ulfet quota unlimited on rec_tbs;
User altered.
SQL> grant dba to ulfet; -- you can give only create session and create table not DBA role
Grant succeeded.
SQL> conn ulfet/ulfet
Connected.
SQL> create table rec_tbl_check (id number);
Table created.
SQL> insert into rec_tbl_check values(1);
1 row created.
SQL> commit;
Commit complete.
--Check tablespace size
SQL> select a.tablespace_name,sum(a.tots/1024/1024) Total_Size_MB, sum(a.sumb/1024/1024) Total_Free_MB
from
(select tablespace_name,0 tots, sum(bytes) sumb from dba_free_space a group by tablespace_name
union
select tablespace_name, sum(bytes) tots, 0 from dba_data_files group by tablespace_name) a
where tablespace_name='REC_TBS'
group by a.tablespace_name;
TABLESPACE_NAME TOTAL_SIZE_MB TOTAL_FREE_MB
------------------------------ ------------- -------------
REC_TBS 50 48.9375
--Now take full backup of database plus archivelogs:
RMAN> backup database plus archivelog;
Starting backup at 05-DEC-12
current log archived
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=40 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=4 RECID=2 STAMP=801229445
input archived log thread=1 sequence=5 RECID=4 STAMP=801231229
channel ORA_DISK_1: starting piece 1 at 05-DEC-12
channel ORA_DISK_1: finished piece 1 at 05-DEC-12
piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_annnn_TAG20121205T121353_8cy0l2f3_.bkp tag=TAG20121205T121353 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:07
Finished backup at 05-DEC-12
Starting backup at 05-DEC-12
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=/u01/app/oracle/oradata/ulfetdb/system01.dbf
input datafile file number=00002 name=/u01/app/oracle/oradata/ulfetdb/sysaux01.dbf
input datafile file number=00005 name=/u01/app/oracle/oradata/ulfetdb/example01.dbf
input datafile file number=00003 name=/u01/app/oracle/oradata/ulfetdb/undotbs01.dbf
input datafile file number=00006 name=/u01/app/oracle/oradata/ulfetdb/rec_tbsp01.dbf
input datafile file number=00004 name=/u01/app/oracle/oradata/ulfetdb/users01.dbf
channel ORA_DISK_1: starting piece 1 at 05-DEC-12
channel ORA_DISK_1: finished piece 1 at 05-DEC-12
piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_nnndf_TAG20121205T121402_8cy0lx6o_.bkp tag=TAG20121205T121402 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:03:36
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 05-DEC-12
channel ORA_DISK_1: finished piece 1 at 05-DEC-12
piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_ncsnf_TAG20121205T121402_8cy0sb8k_.bkp tag=TAG20121205T121402 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:07
Finished backup at 05-DEC-12
Starting backup at 05-DEC-12
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=6 RECID=6 STAMP=801231319
input archived log thread=1 sequence=7 RECID=8 STAMP=801231474
channel ORA_DISK_1: starting piece 1 at 05-DEC-12
channel ORA_DISK_1: finished piece 1 at 05-DEC-12
piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_annnn_TAG20121205T121754_8cy0sm6c_.bkp tag=TAG20121205T121754 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:07
Finished backup at 05-DEC-12
--While taking backup redo logs switched and of course created new archivelogs, let`s take their backup too.
RMAN> backup archivelog all delete input;
Starting backup at 05-DEC-12
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=4 RECID=2 STAMP=801229445
input archived log thread=1 sequence=5 RECID=3 STAMP=801231229
input archived log thread=1 sequence=6 RECID=6 STAMP=801231319
input archived log thread=1 sequence=7 RECID=8 STAMP=801231474
input archived log thread=1 sequence=8 RECID=10 STAMP=801231571
channel ORA_DISK_1: starting piece 1 at 05-DEC-12
channel ORA_DISK_1: finished piece 1 at 05-DEC-12
piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_annnn_TAG20121205T121931_8cy0wn3f_.bkp tag=TAG20121205T121931 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:15
channel ORA_DISK_1: deleting archived log(s)
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH2/1_4_750705673.arc RECID=2 STAMP=801229445
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH/1_5_750705673.arc RECID=3 STAMP=801231229
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH2/1_6_750705673.arc RECID=6 STAMP=801231319
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH2/1_7_750705673.arc RECID=8 STAMP=801231474
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH2/1_8_750705673.arc RECID=10 STAMP=801231571
Finished backup at 05-DEC-12
RMAN>
--Note, I have 2 archivelog locations : ARCH and ARCH2
--Take your current SCN for recovery
SQL> select current_scn from v$database;
CURRENT_SCN
-----------
810170
--Now we can drop tablespace :
SQL> drop tablespace rec_tbs including contents and datafiles;
Tablespace dropped.
--Data file of rec_tbs tablespace was removed
[oracle@localhost ulfetdb]$ ls -lrt rec*
ls: rec*: No such file or directory
--Now recover rec_tbs tablespace
[oracle@localhost ulfetdb]$ export ORACLE_SID=ulfetdb
[oracle@localhost ulfetdb]$ rman target /
Recovery Manager: Release 11.2.0.1.0 - Production on Wed Dec 5 12:32:28 2012
Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved.
connected to target database: ULFETDB (DBID=4080941448)
RMAN> run{
recover tablespace rec_tbs
until scn 810170
auxiliary destination '/home/oracle/';
} 2> 3> 4> 5>
Starting recover at 05-DEC-12
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=41 device type=DISK
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='ABkw'
initialization parameters used for automatic instance:
db_name=ULFETDB
db_unique_name=ABkw_tspitr_ULFETDB
compatible=11.2.0.0.0
db_block_size=8192
db_files=200
sga_target=280M
processes=50
db_create_file_dest=/home/oracle/
log_archive_dest_1='location=/home/oracle/'
#No auxiliary parameter file used
starting up automatic instance ULFETDB
Oracle instance started
Total System Global Area 292933632 bytes
Fixed Size 1336092 bytes
Variable Size 100666596 bytes
Database Buffers 184549376 bytes
Redo Buffers 6381568 bytes
Automatic instance created
List of tablespaces that have been dropped from the target database:
Tablespace rec_tbs
contents of Memory Script:
{
# set requested point in time
set until scn 810170;
# 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 05-DEC-12
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=19 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 /u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_ncsnf_TAG20121205T121402_8cy0sb8k_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_ncsnf_TAG20121205T121402_8cy0sb8k_.bkp tag=TAG20121205T121402
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:04
output file name=/home/oracle/ULFETDB/controlfile/o1_mf_8cy1plp0_.ctl
Finished restore at 05-DEC-12
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 scn 810170;
# 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 6 to
"/u01/app/oracle/oradata/ulfetdb/rec_tbsp01.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, 6;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
renamed tempfile 1 to /home/oracle/ULFETDB/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 05-DEC-12
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 /home/oracle/ULFETDB/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /home/oracle/ULFETDB/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00002 to /home/oracle/ULFETDB/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00006 to /u01/app/oracle/oradata/ulfetdb/rec_tbsp01.dbf
channel ORA_AUX_DISK_1: reading from backup piece /u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_nnndf_TAG20121205T121402_8cy0lx6o_.bkp
channel ORA_AUX_DISK_1: piece handle=/u01/app/oracle/flash_recovery_area/ULFETDB/backupset/2012_12_05/o1_mf_nnndf_TAG20121205T121402_8cy0lx6o_.bkp tag=TAG20121205T121402
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:03:05
Finished restore at 05-DEC-12
datafile 1 switched to datafile copy
input datafile copy RECID=5 STAMP=801232597 file name=/home/oracle/ULFETDB/datafile/o1_mf_system_8cy1px0m_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=6 STAMP=801232597 file name=/home/oracle/ULFETDB/datafile/o1_mf_undotbs1_8cy1px8w_.dbf
datafile 2 switched to datafile copy
input datafile copy RECID=7 STAMP=801232597 file name=/home/oracle/ULFETDB/datafile/o1_mf_sysaux_8cy1px47_.dbf
contents of Memory Script:
{
# set requested point in time
set until scn 810170;
# 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 6 online";
# recover and open resetlogs
recover clone database tablespace "REC_TBS", "SYSTEM", "UNDOTBS1", "SYSAUX" delete 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 6 online
Starting recover at 05-DEC-12
using channel ORA_AUX_DISK_1
starting media recovery
archived log for thread 1 with sequence 6 is already on disk as file /u01/app/oracle/oradata/ulfetdb/ARCH/1_6_750705673.arc
archived log for thread 1 with sequence 7 is already on disk as file /u01/app/oracle/oradata/ulfetdb/ARCH/1_7_750705673.arc
archived log for thread 1 with sequence 8 is already on disk as file /u01/app/oracle/oradata/ulfetdb/ARCH/1_8_750705673.arc
archived log for thread 1 with sequence 9 is already on disk as file /u01/app/oracle/oradata/ulfetdb/ARCH/1_9_750705673.arc
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH/1_6_750705673.arc thread=1 sequence=6
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH/1_7_750705673.arc thread=1 sequence=7
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH/1_8_750705673.arc thread=1 sequence=8
archived log file name=/u01/app/oracle/oradata/ulfetdb/ARCH/1_9_750705673.arc thread=1 sequence=9
media recovery complete, elapsed time: 00:00:05
Finished recover at 05-DEC-12
database opened
contents of Memory Script:
{
# make read only the tablespace that will be exported
sql clone 'alter tablespace REC_TBS read only';
# create directory for datapump import
sql "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/home/oracle/''";
# create directory for datapump export
sql clone "create or replace directory TSPITR_DIROBJ_DPDIR as ''
/home/oracle/''";
}
executing Memory Script
sql statement: alter tablespace REC_TBS read only
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle/''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/home/oracle/''
Performing export of metadata...
EXPDP> Starting "SYS"."TSPITR_EXP_ABkw":
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_ABkw" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_ABkw is:
EXPDP> /home/oracle/tspitr_ABkw_88872.dmp
EXPDP> ******************************************************************************
EXPDP> Datafiles required for transportable tablespace REC_TBS:
EXPDP> /u01/app/oracle/oradata/ulfetdb/rec_tbsp01.dbf
EXPDP> Job "SYS"."TSPITR_EXP_ABkw" successfully completed at 12:39:42
Export completed
contents of Memory Script:
{
# shutdown clone before import
shutdown clone immediate
}
executing Memory Script
database closed
database dismounted
Oracle instance shut down
Performing import of metadata...
IMPDP> Master table "SYS"."TSPITR_IMP_ABkw" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_ABkw":
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_ABkw" successfully completed at 12:41:04
Import completed
contents of Memory Script:
{
# make read write and offline the imported tablespaces
sql 'alter tablespace REC_TBS read write';
sql 'alter tablespace REC_TBS offline';
# enable autobackups after TSPITR is finished
sql 'begin dbms_backup_restore.AutoBackupFlag(TRUE); end;';
}
executing Memory Script
sql statement: alter tablespace REC_TBS read write
sql statement: alter tablespace REC_TBS offline
sql statement: begin dbms_backup_restore.AutoBackupFlag(TRUE); end;
Removing automatic instance
Automatic instance removed
auxiliary instance file /home/oracle/ULFETDB/datafile/o1_mf_temp_8cy1xpjq_.tmp deleted
auxiliary instance file /home/oracle/ULFETDB/onlinelog/o1_mf_3_8cy1xf23_.log deleted
auxiliary instance file /home/oracle/ULFETDB/onlinelog/o1_mf_2_8cy1x5kz_.log deleted
auxiliary instance file /home/oracle/ULFETDB/onlinelog/o1_mf_1_8cy1x0s5_.log deleted
auxiliary instance file /home/oracle/ULFETDB/datafile/o1_mf_sysaux_8cy1px47_.dbf deleted
auxiliary instance file /home/oracle/ULFETDB/datafile/o1_mf_undotbs1_8cy1px8w_.dbf deleted
auxiliary instance file /home/oracle/ULFETDB/datafile/o1_mf_system_8cy1px0m_.dbf deleted
auxiliary instance file /home/oracle/ULFETDB/controlfile/o1_mf_8cy1plp0_.ctl deleted
Finished recover at 05-DEC-12
RMAN>
--As you see result of recovery, it creates automatic instance, then checks tablspaces, using EXPDP/IMPDP transport data etc.
--Why we used auxiliary destination '/home/oracle/' ?
--This is for storing auxiliary instance files.
Check files:
[oracle@localhost ~]$ pwd
/home/oracle
[oracle@localhost ~]$ ls -lrt
total 100
drwxr-xr-x 2 oracle oinstall 4096 May 9 2011 Desktop
drwxr-x--- 3 oracle oinstall 4096 May 9 2011 oradiag_oracle
drwxr-x--- 5 oracle oinstall 4096 Dec 5 12:33 ULFETDB
-rw-r----- 1 oracle oinstall 86016 Dec 5 12:39 tspitr_ABkw_88872.dmp
--Checking datafile.
[oracle@localhost ulfetdb]$ pwd
/u01/app/oracle/oradata/ulfetdb
[oracle@localhost ulfetdb]$ ls -lrt rec_*
-rw-r----- 1 oracle oinstall 52436992 Dec 5 12:46 rec_tbsp01.dbf
--Note that after recover tablespace`s status will stay OFFLINE, alter it :
SQL> select tablespace_name, status from dba_tablespaces where tablespace_name = 'REC_TBS';
TABLESPACE_NAME STATUS
---------------------------------- ---------
REC_TBS OFFLINE
SQL> alter tablespace rec_tbs online;
Tablespace altered.
SQL>
--And now time to check table for inconsistency.
SQL> conn ulfet/ulfet
Connected.
SQL> select * from tab;
TNAME TABTYPE CLUSTERID
------------------------------ ------- ----------
REC_TBL_CHECK TABLE
-- Table recovered. Check table`s data
SQL> select * from rec_tbl_check;
ID
----------
1
SQL>
Yes, we did it.
Detail :
No comments:
Post a Comment