看到这个话题,一般都会想到使用闪回表功能,但我们知道,闪回是基于UNDO,如果UNDO信息已经被覆盖了呢,这个是很常见的,毕竟做了错误操作,不是马上就知道,有可能上午做了误操作,下午才知道呢,这个时候,UNDO很难还能用于上午的闪回。有人说,直接使用闪回数据库吧,那个是否动作太大了一点,如果使用TSPITR(可以见我上次写的文档,PDB表空间如何实现基于时间点恢复PITR呢-CSDN博客)呢,但TSPITR,需要恢复的表空间是自保函的,而且我就修改了一两张表,或者就修改了一张表,要去把整个表空间都后退,那么其他表的数据,会丢失,所以,最好是单独把这个表恢复到过去,甚至恢复为其他名字,和现在的表数据进行对比,是否可以实现呢?答案是肯定的,从12C开始,只恢复一张表到过去某个时间,这个功能,已经支持,弥补了闪回表功能的不足。
当然,基于时间点表的恢复,对数据库有前提:
1.数据库需要开启归档
2.数据库需要正常READ WRITE
对这个需要恢复的表,有一定的限制:
1.不能是SYS用户的表
2.不能是SYSTEM,SYSAUX表空间里面的表
操作上的限制:
1.要恢复PDB中的表,需要连接到CDB$ROOT上操作
下面我们来对此进行验证:
目录
1.环境:
2.需要恢复的表
3.创建模拟表
4.模拟故障
5.执行基于时间点的表恢复
6.验证恢复结果
1.环境:
oracle 19c 19.23
ORACLE LINUX 9.4
2.需要恢复的表
pdborcl 中的 hr.emp1
3.创建模拟表
SQL> conn hr/hr@192.168.133.120:1521/pdborcl
Connected.
SQL> create table emp1 tablespace tsp_test1 as select * from employees;
Table created.
SQL> select count(*) from emp1;
COUNT(*)
----------
107
SQL> R
1* select table_name,tablespace_name from user_tables where table_name='EMP1'
TABLE_NAME TABLESPACE_NAME
------------------------------ ------------------------------
EMP1 TSP_TEST1
SQL> SELECT systimestamp from dual;
SYSTIMESTAMP
---------------------------------------------------------------------------
19-MAY-24 12.01.25.808198 PM +08:00
记住这个时间。
4.模拟故障
SQL> conn hr/hr@192.168.133.120:1521/pdborcl
Connected.
SQL> drop table emp1 purge;
Table dropped.
SQL> select * from emp1;
select * from emp1
*
ERROR at line 1:
ORA-00942: table or view does not exist
5.执行基于时间点的表恢复
oracle@dbserver ~]$ rman target /
Recovery Manager: Release 19.0.0.0.0 - Production on Sun May 19 12:03:36 2024
Version 19.22.0.0.0
Copyright (c) 1982, 2019, Oracle and/or its affiliates. All rights reserved.
connected to target database: ORCLCDB (DBID=2931055914)
RMAN> recover table hr.emp1 of pluggable database pdborcl
2> until time "to_date('2024-05-19 12:01:25','yyyy-mm-dd hh24:mi:ss')"
3> auxiliary destination '/tmp/aux';
Starting recover at 2024-05-19 12:04:31
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=19 device type=DISK
RMAN-05026: warning: presuming following set of tablespaces applies to specified point-in-time
List of tablespaDO segments
Tablespace SYSTEMces expected to have UN
Tablespace PDBORCL:SYSTEM
Tablespace UNDOTBS1
Tablespace PDBORCL:UNDOTBS1
Creating automatic instance, with SID='dDme'
initialization parameters used for automatic instance:
db_name=ORCLCDB
db_unique_name=dDme_pitr_pdborcl_ORCLCDB
compatible=19.0.0
db_block_size=8192
db_files=200
diagnostic_dest=/u01/app/oracle
_pdb_name_case_sensitive=false
_system_trig_enabled=FALSE
sga_target=2240M
processes=200
db_create_file_dest=/tmp/aux
log_archive_dest_1='location=/tmp/aux'
enable_pluggable_database=true
_clone_one_pdb_recovery=true
#No auxiliary parameter file used
starting up automatic instance ORCLCDB
Oracle instance started
Total System Global Area 2348807320 bytes
Fixed Size 9180312 bytes
Variable Size 520093696 bytes
Database Buffers 1811939328 bytes
Redo Buffers 7593984 bytes
Automatic instance created
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2024-05-19 12:01:25','yyyy-mm-dd 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';
}
executing Memory Script
executing command: SET until clause
Starting restore at 2024-05-19 12:04:44
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=91 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 +FRA/ORCLCDB/AUTOBACKUP/2024_05_19/s_1169380139.274.1169380139
channel ORA_AUX_DISK_1: piece handle=+FRA/ORCLCDB/AUTOBACKUP/2024_05_19/s_1169380139.274.1169380139 tag=TAG20240519T114859
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:05
output file name=/tmp/aux/ORCLCDB/controlfile/o1_mf_m4lym160_.ctl
Finished restore at 2024-05-19 12:04:50
sql statement: alter database mount clone database
sql statement: alter system archive log current
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2024-05-19 12:01:25','yyyy-mm-dd hh24:mi:ss')";
# set destinations for recovery set and auxiliary set datafiles
set newname for clone datafile 1 to new;
set newname for clone datafile 9 to new;
set newname for clone datafile 4 to new;
set newname for clone datafile 11 to new;
set newname for clone datafile 3 to new;
set newname for clone datafile 10 to new;
set newname for clone tempfile 1 to new;
set newname for clone tempfile 3 to new;
# switch all tempfiles
switch clone tempfile all;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 1, 9, 4, 11, 3, 10;
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
executing command: SET NEWNAME
executing command: SET NEWNAME
executing command: SET NEWNAME
renamed tempfile 1 to /tmp/aux/ORCLCDB/datafile/o1_mf_temp_%u_.tmp in control file
renamed tempfile 3 to /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_temp_%u_.tmp in control file
Starting restore at 2024-05-19 12:04:54
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 /tmp/aux/ORCLCDB/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00004 to /tmp/aux/ORCLCDB/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00003 to /tmp/aux/ORCLCDB/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece +FRA/ORCLCDB/BACKUPSET/2024_05_19/nnndf0_tag20240519t114756_0.287.1169380077
channel ORA_AUX_DISK_1: piece handle=+FRA/ORCLCDB/BACKUPSET/2024_05_19/nnndf0_tag20240519t114756_0.287.1169380077 tag=TAG20240519T114756
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:15
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 00009 to /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_system_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00011 to /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_undotbs1_%u_.dbf
channel ORA_AUX_DISK_1: restoring datafile 00010 to /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_sysaux_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece +FRA/ORCLCDB/107B00529A4E9350E0637885A8C036A8/BACKUPSET/2024_05_19/nnndf0_tag20240519t114756_0.283.1169380107
channel ORA_AUX_DISK_1: piece handle=+FRA/ORCLCDB/107B00529A4E9350E0637885A8C036A8/BACKUPSET/2024_05_19/nnndf0_tag20240519t114756_0.283.1169380107 tag=TAG20240519T114756
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:07
Finished restore at 2024-05-19 12:05:17
datafile 1 switched to datafile copy
input datafile copy RECID=133 STAMP=1169381118 file name=/tmp/aux/ORCLCDB/datafile/o1_mf_system_m4lym7o5_.dbf
datafile 9 switched to datafile copy
input datafile copy RECID=134 STAMP=1169381118 file name=/tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_system_m4lympt8_.dbf
datafile 4 switched to datafile copy
input datafile copy RECID=135 STAMP=1169381118 file name=/tmp/aux/ORCLCDB/datafile/o1_mf_undotbs1_m4lym7od_.dbf
datafile 11 switched to datafile copy
input datafile copy RECID=136 STAMP=1169381118 file name=/tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_undotbs1_m4lymptb_.dbf
datafile 3 switched to datafile copy
input datafile copy RECID=137 STAMP=1169381118 file name=/tmp/aux/ORCLCDB/datafile/o1_mf_sysaux_m4lym7o9_.dbf
datafile 10 switched to datafile copy
input datafile copy RECID=138 STAMP=1169381118 file name=/tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_sysaux_m4lympt5_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2024-05-19 12:01:25','yyyy-mm-dd hh24:mi:ss')";
# online the datafiles restored or switched
sql clone "alter database datafile 1 online";
sql clone 'PDBORCL' "alter database datafile
9 online";
sql clone "alter database datafile 4 online";
sql clone 'PDBORCL' "alter database datafile
11 online";
sql clone "alter database datafile 3 online";
sql clone 'PDBORCL' "alter database datafile
10 online";
# recover and open database read only
recover clone database tablespace "SYSTEM", "PDBORCL":"SYSTEM", "UNDOTBS1", "PDBORCL":"UNDOTBS1", "SYSAUX", "PDBORCL":"SYSAUX";
sql clone 'alter database open read only';
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 1 online
sql statement: alter database datafile 9 online
sql statement: alter database datafile 4 online
sql statement: alter database datafile 11 online
sql statement: alter database datafile 3 online
sql statement: alter database datafile 10 online
Starting recover at 2024-05-19 12:05:18
using channel ORA_AUX_DISK_1
Executing: alter database datafile 7 offline
Executing: alter database datafile 5, 6, 8 offline
Executing: alter database datafile 12, 19, 20, 23, 24 offline
Executing: alter database datafile 13, 14, 15, 16, 17, 18 offline
starting media recovery
archived log for thread 1 with sequence 8 is already on disk as file /u01/app/oracle/arch_log/1_8_1169372078.dbf
archived log for thread 1 with sequence 9 is already on disk as file /u01/app/oracle/arch_log/1_9_1169372078.dbf
archived log for thread 1 with sequence 10 is already on disk as file /u01/app/oracle/arch_log/1_10_1169372078.dbf
archived log for thread 1 with sequence 11 is already on disk as file /u01/app/oracle/arch_log/1_11_1169372078.dbf
archived log file name=/u01/app/oracle/arch_log/1_8_1169372078.dbf thread=1 sequence=8
archived log file name=/u01/app/oracle/arch_log/1_9_1169372078.dbf thread=1 sequence=9
archived log file name=/u01/app/oracle/arch_log/1_10_1169372078.dbf thread=1 sequence=10
archived log file name=/u01/app/oracle/arch_log/1_11_1169372078.dbf thread=1 sequence=11
media recovery complete, elapsed time: 00:00:02
Finished recover at 2024-05-19 12:05:23
sql statement: alter database open read only
contents of Memory Script:
{
sql clone 'alter pluggable database PDBORCL open read only';
}
executing Memory Script
sql statement: alter pluggable database PDBORCL open read only
contents of Memory Script:
{
sql clone "create spfile from memory";
shutdown clone immediate;
startup clone nomount;
sql clone "alter system set control_files =
''/tmp/aux/ORCLCDB/controlfile/o1_mf_m4lym160_.ctl'' comment=
''RMAN set'' scope=spfile";
shutdown clone immediate;
startup clone nomount;
# mount database
sql clone 'alter database mount clone database';
}
executing Memory Script
sql statement: create spfile from memory
database closed
database dismounted
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 2348807320 bytes
Fixed Size 9180312 bytes
Variable Size 520093696 bytes
Database Buffers 1811939328 bytes
Redo Buffers 7593984 bytes
sql statement: alter system set control_files = ''/tmp/aux/ORCLCDB/controlfile/o1_mf_m4lym160_.ctl'' comment= ''RMAN set'' scope=spfile
Oracle instance shut down
connected to auxiliary database (not started)
Oracle instance started
Total System Global Area 2348807320 bytes
Fixed Size 9180312 bytes
Variable Size 520093696 bytes
Database Buffers 1811939328 bytes
Redo Buffers 7593984 bytes
sql statement: alter database mount clone database
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2024-05-19 12:01:25','yyyy-mm-dd hh24:mi:ss')";
# set destinations for recovery set and auxiliary set datafiles
set newname for datafile 23 to new;
# restore the tablespaces in the recovery set and the auxiliary set
restore clone datafile 23;
switch clone datafile all;
}
executing Memory Script
executing command: SET until clause
executing command: SET NEWNAME
Starting restore at 2024-05-19 12:06:30
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=14 device type=DISK
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 00023 to /tmp/aux/DDME_PITR_PDBORCL_ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_tsp_test_%u_.dbf
channel ORA_AUX_DISK_1: reading from backup piece +FRA/ORCLCDB/107B00529A4E9350E0637885A8C036A8/BACKUPSET/2024_05_19/nnndf0_tag20240519t114756_0.283.1169380107
channel ORA_AUX_DISK_1: piece handle=+FRA/ORCLCDB/107B00529A4E9350E0637885A8C036A8/BACKUPSET/2024_05_19/nnndf0_tag20240519t114756_0.283.1169380107 tag=TAG20240519T114756
channel ORA_AUX_DISK_1: restored backup piece 1
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:01
Finished restore at 2024-05-19 12:06:32
datafile 23 switched to datafile copy
input datafile copy RECID=140 STAMP=1169381192 file name=/tmp/aux/DDME_PITR_PDBORCL_ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_tsp_test_m4lyp74p_.dbf
contents of Memory Script:
{
# set requested point in time
set until time "to_date('2024-05-19 12:01:25','yyyy-mm-dd hh24:mi:ss')";
# online the datafiles restored or switched
sql clone 'PDBORCL' "alter database datafile
23 online";
# recover and open resetlogs
recover clone database tablespace "PDBORCL":"TSP_TEST1", "SYSTEM", "PDBORCL":"SYSTEM", "UNDOTBS1", "PDBORCL":"UNDOTBS1", "SYSAUX", "PDBORCL":"SYSAUX" delete archivelog;
alter clone database open resetlogs;
}
executing Memory Script
executing command: SET until clause
sql statement: alter database datafile 23 online
Starting recover at 2024-05-19 12:06:32
using channel ORA_AUX_DISK_1
Executing: alter database datafile 7 offline
Executing: alter database datafile 5, 6, 8 offline
Executing: alter database datafile 12, 19, 20, 24 offline
Executing: alter database datafile 13, 14, 15, 16, 17, 18 offline
starting media recovery
archived log for thread 1 with sequence 8 is already on disk as file /u01/app/oracle/arch_log/1_8_1169372078.dbf
archived log for thread 1 with sequence 9 is already on disk as file /u01/app/oracle/arch_log/1_9_1169372078.dbf
archived log for thread 1 with sequence 10 is already on disk as file /u01/app/oracle/arch_log/1_10_1169372078.dbf
archived log for thread 1 with sequence 11 is already on disk as file /u01/app/oracle/arch_log/1_11_1169372078.dbf
archived log file name=/u01/app/oracle/arch_log/1_8_1169372078.dbf thread=1 sequence=8
archived log file name=/u01/app/oracle/arch_log/1_9_1169372078.dbf thread=1 sequence=9
archived log file name=/u01/app/oracle/arch_log/1_10_1169372078.dbf thread=1 sequence=10
archived log file name=/u01/app/oracle/arch_log/1_11_1169372078.dbf thread=1 sequence=11
media recovery complete, elapsed time: 00:00:01
Finished recover at 2024-05-19 12:06:35
database opened
contents of Memory Script:
{
sql clone 'alter pluggable database PDBORCL open';
}
executing Memory Script
sql statement: alter pluggable database PDBORCL open
contents of Memory Script:
{
# create directory for datapump import
sql 'PDBORCL' "create or replace directory
TSPITR_DIROBJ_DPDIR as ''
/tmp/aux''";
# create directory for datapump export
sql clone 'PDBORCL' "create or replace directory
TSPITR_DIROBJ_DPDIR as ''
/tmp/aux''";
}
executing Memory Script
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/tmp/aux''
sql statement: create or replace directory TSPITR_DIROBJ_DPDIR as ''/tmp/aux''
Performing export of tables...
EXPDP> Starting "SYS"."TSPITR_EXP_dDme_jzjA":
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
EXPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
EXPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
EXPDP> . . exported "HR"."EMP1" 17.08 KB 107 rows
EXPDP> Master table "SYS"."TSPITR_EXP_dDme_jzjA" successfully loaded/unloaded
EXPDP> ******************************************************************************
EXPDP> Dump file set for SYS.TSPITR_EXP_dDme_jzjA is:
EXPDP> /tmp/aux/tspitr_dDme_48488.dmp
EXPDP> Job "SYS"."TSPITR_EXP_dDme_jzjA" successfully completed at Sun May 19 12:08:08 2024 elapsed 0 00:01:02
Export completed
contents of Memory Script:
{
# shutdown clone before import
shutdown clone abort
}
executing Memory Script
Oracle instance shut down
Performing import of tables...
IMPDP> Master table "SYS"."TSPITR_IMP_dDme_wCqq" successfully loaded/unloaded
IMPDP> Starting "SYS"."TSPITR_IMP_dDme_wCqq":
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
IMPDP> . . imported "HR"."EMP1" 17.08 KB 107 rows
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
IMPDP> Job "SYS"."TSPITR_IMP_dDme_wCqq" successfully completed at Sun May 19 12:08:22 2024 elapsed 0 00:00:08
Import completed
Removing automatic instance
Automatic instance removed
auxiliary instance file /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_temp_m4lyn80g_.tmp deleted
auxiliary instance file /tmp/aux/ORCLCDB/datafile/o1_mf_temp_m4lyn3wb_.tmp deleted
auxiliary instance file /tmp/aux/DDME_PITR_PDBORCL_ORCLCDB/onlinelog/o1_mf_3_m4lypcw7_.log deleted
auxiliary instance file /tmp/aux/DDME_PITR_PDBORCL_ORCLCDB/onlinelog/o1_mf_2_m4lypctq_.log deleted
auxiliary instance file /tmp/aux/DDME_PITR_PDBORCL_ORCLCDB/onlinelog/o1_mf_1_m4lypcss_.log deleted
auxiliary instance file /tmp/aux/DDME_PITR_PDBORCL_ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_tsp_test_m4lyp74p_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_sysaux_m4lympt5_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/datafile/o1_mf_sysaux_m4lym7o9_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_undotbs1_m4lymptb_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/datafile/o1_mf_undotbs1_m4lym7od_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/107B00529A4E9350E0637885A8C036A8/datafile/o1_mf_system_m4lympt8_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/datafile/o1_mf_system_m4lym7o5_.dbf deleted
auxiliary instance file /tmp/aux/ORCLCDB/controlfile/o1_mf_m4lym160_.ctl deleted
auxiliary instance file tspitr_dDme_48488.dmp deleted
Finished recover at 2024-05-19 12:08:23
RMAN>
6.验证恢复结果
RMAN> select tablespace_name,status from cdb_tablespaces;
TABLESPACE_NAME STATUS
------------------------------ ---------
TSP_TEST1 ONLINE
。。。
19 rows selected
[oracle@dbserver ~]$ sqlplus hr/hr@192.168.133.120:1521/pdborcl
SQL*Plus: Release 19.0.0.0.0 - Production on Sun May 19 12:11:29 2024
Version 19.22.0.0.0
Copyright (c) 1982, 2023, Oracle. All rights reserved.
Last Successful login time: Sun May 19 2024 12:02:18 +08:00
Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.22.0.0.0
SQL> select count(*) from emp1;
COUNT(*)
----------
107
SQL> update emp1 set salary=salary+1 ; --可以直接修改
107 rows updated.
SQL> rollback;
Rollback complete.
SQL>
到此,基于时间点的表恢复,已经完成。
|