Oracle Study之案例--数据恢复神器Flashback(3)

简介:

Flashback Database:

wKioL1S2K8jiKqpfAAQIa7fTYOc265.jpg


案例分析:

      flashback database:利用flashback log 对整个database 做回退到过去的某个时间点(用于DDL 的误操作如drop 和 truncate),类似于RMAN的不完全恢复(media recovery incompelete)

1
因为flashback database是不完全恢复,在恢复到过去的时间点前应该对数据库备份!
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
1 、查看flashback database是否开启
07 : 21 : 27  SQL> select flashback_on  from  v$database;                                                                                       
FLASHBACK_ON
------------------
NO
 
2 、创建recovery area
07 : 21 : 33  SQL> show parameter recover                                                                                                     
NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
db_recovery_file_dest                string      /u01/app/oracle/flash_recovery
                                                  _area
db_recovery_file_dest_size           big integer 2G
recovery_parallelism                 integer      2                                                                                                   ---recovery area可以存储flashback log、archive log、rman backup等                      
[oracle@work ~]$ mkdir -p /disk1/recovery/prod
 
配置recovery area:
07 : 22 : 49  SQL> alter system set db_recovery_file_dest= '/disk1/recovery/prod'  scope=spfile;                                                
System altered.
 
在归档模式下启用flashback database:
 
07 : 25 : 06  SQL> alter database flashback  on ;                                                                                               
Database altered.
 
07 : 25 : 29  SQL> select flashback_on  from  v$database;                                                                                       
FLASHBACK_ON
------------------
YES
 
07 : 25 : 38  SQL> alter database open;                                                                                                       
Database altered.
 
案例 1 :flashback database恢复DDL误操作(基于SCN)
 
flashback database可以用于基于时间点或SCN的数据恢复(可以通过logminer来查看DDL操作的时间点)
 
1 )模拟环境
15 : 18 : 17  SYS@ test1 >select current_scn  from  v$database;
 
CURRENT_SCN
-----------
    1264788
    
07 : 26 : 30  SQL> select *  from  test;                                                                                                        
      EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       7499  ALLEN      SALESMAN         7698  20 -FEB -81        1600         300          30
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       7499  ALLEN      SALESMAN         7698  20 -FEB -81        1600         300          30
       7521  WARD       SALESMAN         7698  22 -FEB -81        1250         500          30
       7566  JONES      MANAGER          7839  02 -APR -81        2975                     20
       7654  MARTIN     SALESMAN         7698  28 -SEP -81        1250        1400          30
       7698  BLAKE      MANAGER          7839  01 -MAY -81        2850                     30
       7782  CLARK      MANAGER          7839  09 -JUN -81        2450                     10
       7788  SCOTT      ANALYST          7566  19 -APR -87        3000                     20
       7839  KING       PRESIDENT             17 -NOV -81        5000                     10
       7844  TURNER     SALESMAN         7698  08 -SEP -81        1500           0          30
       7876  ADAMS      CLERK            7788  23 -MAY -87        1100                     20
       7900  JAMES      CLERK            7698  03 -DEC -81         950                     30
       7902  FORD       ANALYST          7566  03 -DEC -81        3000                     20
       7934  MILLER     CLERK            7782  23 -JAN -82        1300                     10
16  rows selected.
07 : 26 : 36  SQL> drop table test purge;                                                                                                     
Table dropped.
 
07 : 27 : 20  SQL> create table test  as  select *  from  emp  where  rownum= 1 ;                                                                     
Table created.
07 : 27 : 25  SQL> select *  from  test;                                                                                                        
      EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       
查看flashback 日志:
[oracle@work ~]$ ls /disk1/recovery/prod/PROD/flashback/
o1_mf_74q999lb_.flb
 
关闭数据库后,在mount状态下恢复:
07 : 29 : 22  SQL> shutdown immediate                                                                                                      
Database closed.
Database dismounted.
ORACLE instance shut down.
 
07 : 29 : 53  SQL> startup mount                                                                                                              
ORACLE instance started.
Total System Global Area   314572800  bytes
Fixed Size                   1219184  bytes
Variable Size               71304592  bytes
Database Buffers           239075328  bytes
Redo Buffers                 2973696  bytes
Database mounted.
 
通过flashback database将库恢复到过去的scn:
07 : 30 : 02  SQL> flashback database to scn  1264788 ;                                                                                         
Flashback complete.
 
将database以read only方式打开,先验证下恢复是否成功,如果不成功,再从新进入mount下恢复
07 : 31 : 29  SQL> alter database open read only;                                                                                             
Database altered.
 
07 : 31 : 34  SQL> select *  from  scott.test;                                                                                                  
      EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       7499  ALLEN      SALESMAN         7698  20 -FEB -81        1600         300          30
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       7499  ALLEN      SALESMAN         7698  20 -FEB -81        1600         300          30
       7521  WARD       SALESMAN         7698  22 -FEB -81        1250         500          30
       7566  JONES      MANAGER          7839  02 -APR -81        2975                     20
       7654  MARTIN     SALESMAN         7698  28 -SEP -81        1250        1400          30
       7698  BLAKE      MANAGER          7839  01 -MAY -81        2850                     30
       7782  CLARK      MANAGER          7839  09 -JUN -81        2450                     10
       7788  SCOTT      ANALYST          7566  19 -APR -87        3000                     20
       7839  KING       PRESIDENT             17 -NOV -81        5000                     10
       7844  TURNER     SALESMAN         7698  08 -SEP -81        1500           0          30
       7876  ADAMS      CLERK            7788  23 -MAY -87        1100                     20
       7900  JAMES      CLERK            7698  03 -DEC -81         950                     30
       7902  FORD       ANALYST          7566  03 -DEC -81        3000                     20
       7934  MILLER     CLERK            7782  23 -JAN -82        1300                     10
16  rows selected.
 
--恢复成功,重新以resetlogs的方式open database
07 : 31 : 40  SQL> shutdown immedaite                                                                                                         
SP2 -0717 : illegal SHUTDOWN option
07 : 31 : 45  SQL> shutdown immediate                                                                                                         
Database closed.
Database dismounted.
ORACLE instance shut down.
07 : 32 : 02  SQL> startup mount                                                                                                              
ORACLE instance started.
Total System Global Area   314572800  bytes
Fixed Size                   1219184  bytes
Variable Size               71304592  bytes
Database Buffers           239075328  bytes
Redo Buffers                 2973696  bytes
Database mounted.
07 : 32 : 10  SQL> alter database open resetlogs;                                                                                             
Database altered.
 
验证:
07 : 32 : 25  SQL> select *  from  scott.test;                                                                                                  
      EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       7499  ALLEN      SALESMAN         7698  20 -FEB -81        1600         300          30
       7369  SMITH      CLERK            7902  17 -DEC -80         800                     20
       7499  ALLEN      SALESMAN         7698  20 -FEB -81        1600         300          30
       7521  WARD       SALESMAN         7698  22 -FEB -81        1250         500          30
       7566  JONES      MANAGER          7839  02 -APR -81        2975                     20
       7654  MARTIN     SALESMAN         7698  28 -SEP -81        1250        1400          30
       7698  BLAKE      MANAGER          7839  01 -MAY -81        2850                     30
       7782  CLARK      MANAGER          7839  09 -JUN -81        2450                     10
       7788  SCOTT      ANALYST          7566  19 -APR -87        3000                     20
       7839  KING       PRESIDENT             17 -NOV -81        5000                     10