Increase Space in Redo Logs

The number and size of the Redo log files is an important performance consideration. Redo log files are created when the database is created.

To increase space in the Redo logs

  1. Log in to Oracle using SQL*Plus as SYSDBA or SYSOPER and run the following script to create eight Redo logs that are 2 MB each:
    rem -- parm1 -- temp dir
    
    rem Generate creation script
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_11.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_11.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_12.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_12.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_13.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_13.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_14.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_14.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_15.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_15.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_16.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_16.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_17.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_17.LOG' )
     UNION
    
    SELECT 'ALTER DATABASE ADD LOGFILE '''
        ||  SUBSTR ( MEMBER , 1 , INSTR ( MEMBER , '\' , -1 , 1 ) )
        || 'REDO_18.LOG'' SIZE 2M ;'
      from V$LOGFILE
     where ROWNUM = 1
       and not exists ( SELECT 1 from V$LOGFILE where MEMBER like '%REDO_18.LOG' )
    .
     Spool &1.AddLog.ORA
    /
    Spool Off
    COMMIT ;
    
    SELECT 'ALTER SYSTEM SWITCH LOGFILE ;' from V$LOG where ROWNUM < 5
    .
     Spool &1.SwtchLog.ORA
    /
    Spool Off
    COMMIT ;
    
    rem Generate Deletion script
    SELECT 'ALTER DATABASE DROP LOGFILE GROUP ' || TO_CHAR ( GROUP# ) || ' ;' from V$LOG where BYTES < 2097152
    .
     Spool &1.DropLog.ORA
    /
    Spool Off
    COMMIT ;
    
    @&1.AddLog.ORA
    $Del &1.AddLog.ORA
    COMMIT ;
     
    @&1.SwtchLog.ORA
    $Del &1.SwtchLog.ORA
    COMMIT ;
     
    @&1.DropLog.ORA
    $Del &1.DropLog.ORA
    COMMIT ;
    
  2. Run the following query to verify the new Redo log configuration:
    SQLWKS> select group#, status, bytes from v$log;
    

Note: Oracle does not let you drop an older Redo log file that is still ACTIVE. If you must drop an older Redo log file that is still ACTIVE, drop that log file manually.