Nologging and Recovery !
این امکان وجود دارد که شما برای بعضی از کار ها از پایگاه داده بخواهید که redo برای آنکار تولید نکند. مثل create table as select, insert into select, create index, ... اگر شما بعد از این عملیات ها بکاپ تهیه کنید هیچ مشکلی نیست و شما به درستی زمان کمتری برای انجام آنکارها گذاشته اید. ولی اگر قبل از بکاپ دیتافایل آسیب ببیند چه مشکلی بوجود می آید ؟
بیایید با هم یک سناریو را دنبال کنیم:
اول یک tablespace و user جدا و دسترسی های لازم را ایجاد میکنیم:
[oracle@myos ~]$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Mon Jul 3 11:09:42 2017 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, Automatic Storage Management, OLAP, Data Mining and Real Application Testing options SYS@db11g> create tablespace mas datafile '+DATA'; Tablespace created. SYS@db11g> create user masoud account unlock identified by masoud default tablespace mas quota unlimited on mas; User created. SYS@db11g> grant create table, create session, create sequence to masoud; Grant succeeded. SYS@db11g> disc Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, Automatic Storage Management, OLAP, Data Mining and Real Application Testing options @> conn masoud Enter password: Connected. MASOUD@db11g> create sequence myseq; Sequence created. MASOUD@db11g> create table t (c1 number, c2 varchar(10)); Table created.
خوب در اینجا ما یک user به نام masoud داریم که tablespace پیش فرض اون mas هست حال داده در جدول t میریزیم
begin for i in 1..1000 loop insert into t values (myseq.nextval, 'my val'); end loop; commit; end; /
حال یک بکاپ از tablespace میگیریم :
RMAN> backup tablespace mas; Starting backup at 03-JUL-2017 11:25:01 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=2591 device type=DISK allocated channel: ORA_DISK_2 channel ORA_DISK_2: SID=11 device type=DISK allocated channel: ORA_DISK_3 channel ORA_DISK_3: SID=528 device type=DISK allocated channel: ORA_DISK_4 channel ORA_DISK_4: SID=1044 device type=DISK channel ORA_DISK_1: starting full datafile backup set channel ORA_DISK_1: specifying datafile(s) in backup set input datafile file number=00019 name=+DATA/db11g/datafile/mas.265.948366897 channel ORA_DISK_1: starting piece 1 at 03-JUL-2017 11:25:04 channel ORA_DISK_1: finished piece 1 at 03-JUL-2017 11:25:07 piece handle=+FRA/db11g/backupset/2017_07_03/nnndf0_tag20170703t112504_0.284.948367505 tag=TAG20170703T112504 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:03 Finished backup at 03-JUL-2017 11:25:07 Starting Control File and SPFILE Autobackup at 03-JUL-2017 11:25:08 piece handle=+FRA/db11g/autobackup/2017_07_03/s_948367508.429.948367511 comment=NONE Finished Control File and SPFILE Autobackup at 03-JUL-2017 11:25:15
حالا وضعیت قابل ریکاور بودن datafile رو ببینیم:
RMAN> report unrecoverable; Report of files that need backup due to unrecoverable operations File Type of Backup Required Name ---- ----------------------- -----------------------------------
پس همانگونه که میبینید هیچ datafile unrecoverable نیست (در حقیقت همه در صورت media failure قابل بازگشت هستند) حال یک عملیات nologging انجام میدهیم:
MASOUD@db11g> create index ix_t_c1 on t(c1) nologging; Index created. RMAN> report unrecoverable; Report of files that need backup due to unrecoverable operations File Type of Backup Required Name ---- ----------------------- ----------------------------------- 19 full or incremental +DATA/db11g/datafile/mas.265.948366897 SYS@db11g> select file#,to_char(UNRECOVERABLE_TIME,'yyyy-mm-dd:hh24:mi:ss') from v$datafile where file#=19; FILE# TO_CHAR(UNRECOVERAB ---------- ------------------- 19 2017-07-03:14:17:01
همانگونه که مشاهده نمودید datafile شماره ۱۹ unrecoverable شد.
بیاید فرض کنیم که دیتافایل دچار آسیب شده و حال میخواهیم آن را recover کنیم:
RMAN> sql 'alter database datafile 19 offline'; using target database control file instead of recovery catalog sql statement: alter database datafile 19 offline RMAN> restore datafile 19; . . . Finished restore at 03-JUL-2017 14:30:43 RMAN> recover datafile 19; Starting recover at 03-JUL-2017 14:31:06 using channel ORA_DISK_1 using channel ORA_DISK_2 using channel ORA_DISK_3 using channel ORA_DISK_4 starting media recovery media recovery complete, elapsed time: 00:00:03 Finished recover at 03-JUL-2017 14:31:10 RMAN> sql 'alter database datafile 19 online'; sql statement: alter database datafile 19 online
بسیار خوب فایل recover شد حال یک select میزنیم و سعی میکنیم تا از index استفاده شود.
MASOUD@db11g> select * from t where c1=7; select * from t where c1=7 * ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 19, block # 140) ORA-01110: data file 19: '+DATA/db11g/datafile/mas.265.948366897' ORA-26040: Data block was loaded using the NOLOGGING option
بدرستی با مشکل رو به رو شدیم، چون ما redo برای این index ایجاد نکرده بودیم پس index هم زمان recovery نخواهیم داشت. ولی میتوانیم ببنیم دفیقا کدام index این مشکل رو ایجاد کرده و با کمی پیچیدگی میتوانیم این مشکل را حل کنیم:
MASOUD@db11g> select index_name,status,logging from user_indexes where tablespace_name='MAS'; INDEX_NAME STATUS LOG ------------------------------ -------- --- IX_T_C1 VALID NO MASOUD@db11g> alter index IX_T_C1 rebuild nologging;
alter index IX_T_C1 rebuild nologging
* ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 19, block # 140)
ORA-01110: data file 18: '+DATA/db11g/datafile/mas.265.948366897'
ORA-26040: Data block was loaded using the NOLOGGING option MASOUD@db11g> alter index IX_T_C1 unusable; MASOUD@db11g> alter index ix_t_c1 rebuild nologging; Index altered. MASOUD@db11g> select * from t where c1=7; C1 C2 ---------- ---------- 7 my val
بسیار خوب همانگونه که دیدید مشکل حل شد و حال دوباره از tablespace بکاپ میگیریم که مشکل unrecoverable نیز نداشته باشیم.
RMAN> backup tablespace mas; Finished backup at 03-JUL-2017 14:56:27 RMAN> report unrecoverable; Report of files that need backup due to unrecoverable operations File Type of Backup Required Name ---- ----------------------- -----------------------------------
حالا رفتار insert nologging را ببینیم:
MASOUD@db11g> alter table t nologging; Table altered. MASOUD@db11g> insert /*+ append */ into t select * from t; 1000 rows created. SYS@db11g> select file#,to_char(UNRECOVERABLE_TIME,'yyyy-mm-dd:hh24:mi:ss') from v$datafile where file#=19; FILE# TO_CHAR(UNRECOVERAB ---------- ------------------- 19 2017-07-03:15:00:01 RMAN> report unrecoverable; Report of files that need backup due to unrecoverable operations File Type of Backup Required Name ---- ----------------------- ----------------------------------- 19 full or incremental +DATA/db11g/datafile/mas.265.948366897 RMAN> sql 'alter database datafile 19 offline'; sql statement: alter database datafile 19 offline RMAN> restore datafile 19; Starting restore at 03-JUL-2017 15:05:49 using channel ORA_DISK_1 using channel ORA_DISK_2 using channel ORA_DISK_3 using channel ORA_DISK_4 channel ORA_DISK_1: starting datafile backup set restore channel ORA_DISK_1: specifying datafile(s) to restore from backup set channel ORA_DISK_1: restoring datafile 00019 to +DATA/db11g/datafile/mas.265.948366897 channel ORA_DISK_1: reading from backup piece +FRA/db11g/backupset/2017_07_03/nnndf0_tag20170703t145624_0.393.948380185 channel ORA_DISK_1: piece handle=+FRA/db11g/backupset/2017_07_03/nnndf0_tag20170703t145624_0.393.948380185 tag=TAG20170703T145624 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:03 Finished restore at 03-JUL-2017 15:05:52 RMAN> recover datafile 19; Starting recover at 03-JUL-2017 15:05:59 using channel ORA_DISK_1 using channel ORA_DISK_2 using channel ORA_DISK_3 using channel ORA_DISK_4 starting media recovery media recovery complete, elapsed time: 00:00:02 Finished recover at 03-JUL-2017 15:06:03 RMAN> sql 'alter database datafile 19 online'; sql statement: alter database datafile 19 online MASOUD@db11g> select * from t; . . . ERROR: ORA-01578: ORACLE data block corrupted (file # 19, block # 136) ORA-01110: data file 19: '+DATA/db11g/datafile/mas.265.948366897' ORA-26040: Data block was loaded using the NOLOGGING option
همانگونه که مشاهده نمودید به مشکل برخوردیم و متاسفانه راهی برای برگرداندن دیتا وجود ندارد و این هزینه ای هست که در مقابل حذف redo و افزایش سرعت میپردازید.
دوستان عزیز امیدوارم مطلب کاربردی بوده باشد.
شاد و پیروز باشید.