Before looking at the tasks involved to perform the resize, let's look at the current online redo log groups and their sizes:
SQL> SELECT a.group#, a.member, b.bytes
2 FROM v$logfile a, v$log b WHERE a.group# = b.group#;
GROUP# MEMBER BYTES
---------- ---------------------------------------- ------------
1 /u03/app/oradata/ORA920/redo_g01a.log 104,857,600
1 /u04/app/oradata/ORA920/redo_g01b.log 104,857,600
1 /u05/app/oradata/ORA920/redo_g01c.log 104,857,600
2 /u03/app/oradata/ORA920/redo_g02a.log 104,857,600
2 /u04/app/oradata/ORA920/redo_g02b.log 104,857,600
2 /u05/app/oradata/ORA920/redo_g02c.log 104,857,600
3 /u03/app/oradata/ORA920/redo_g03a.log 104,857,600
3 /u04/app/oradata/ORA920/redo_g03b.log 104,857,600
3 /u05/app/oradata/ORA920/redo_g03c.log 104,857,600
9 rows selected.
Now let's take a look at the steps involved to resize / recreate all online redo log groups:
- Make the last redo log CURRENT
Force a log switch until the last redo log is marked "CURRENT" by issuing the following command:
SQL> select group#, status from v$log;
GROUP# STATUS
---------- ----------------
1 CURRENT
2 INACTIVE
3 INACTIVE
SQL> alter system switch logfile;
SQL> alter system switch logfile;
SQL> select group#, status from v$log;
GROUP# STATUS
---------- ----------------
1 INACTIVE
2 INACTIVE
3 CURRENT - Drop first redo log
After making the last online redo log file the CURRENT one, drop the first online redo log:
SQL> alter database drop logfile group 1;
Database altered. - Re-create dropped online redo log group
Re-create the dropped redo log group with different size (if desired):
SQL> alter database add logfile group 1 (
2 '/u03/app/oradata/ORA920/redo_g01a.log',
3 '/u04/app/oradata/ORA920/redo_g01b.log',
4 '/u05/app/oradata/ORA920/redo_g01c.log') size 250m reuse;
Database altered. - Force another log switch
After re-creating the online redo log group, force a log switch. The online redo log group just created should become the "CURRENT" one:
SQL> select group#, status from v$log;
GROUP# STATUS
---------- ----------------
1 UNUSED
2 INACTIVE
3 CURRENT
SQL> alter system switch logfile;
SQL> select group#, status from v$log;
GROUP# STATUS
---------- ----------------
1 CURRENT
2 INACTIVE
3 ACTIVE - Loop back to Step 2 until all logs are rebuilt
After re-creating an online redo log group, continue to re-create (or resize) all online redo log groups until all of them are rebuilt.
After rebuilding (resizing) all online redo log groups, here is a snapshot of all physical files:
SQL> SELECT a.group#, a.member, b.bytes
2 FROM v$logfile a, v$log b WHERE a.group# = b.group#;
GROUP# MEMBER BYTES
---------- ---------------------------------------- ------------
1 /u03/app/oradata/ORA920/redo_g01a.log 262,144,000
1 /u04/app/oradata/ORA920/redo_g01b.log 262,144,000
1 /u05/app/oradata/ORA920/redo_g01c.log 262,144,000
2 /u03/app/oradata/ORA920/redo_g02a.log 262,144,000
2 /u04/app/oradata/ORA920/redo_g02b.log 262,144,000
2 /u05/app/oradata/ORA920/redo_g02c.log 262,144,000
3 /u03/app/oradata/ORA920/redo_g03a.log 262,144,000
3 /u04/app/oradata/ORA920/redo_g03b.log 262,144,000
3 /u05/app/oradata/ORA920/redo_g03c.log 262,144,000
9 rows selected.
No comments:
Post a Comment