Tuesday, March 31, 2015

Recursion in Oracle 12

Oracle 12 has a new parameter called PGA_AGGREGATE_LIMIT:

SQL> conn system/manager
Connected.
SQL> l
  1  select value from v$parameter
  2* where name = 'pga_aggregate_limit'
SQL> /
 
VALUE
--------------------
2147483648
 
SQL>

You cannot set it below 2 gigabytes:

SQL> alter system
  2  set pga_aggregate_limit = 1g;
alter system
*
ERROR at line 1:
ORA-02097: parameter cannot be modified because
specified value is invalid
ORA-00093: pga_aggregate_limit must be between 2048M
and 100000G
 
SQL> 

In earlier versions of Oracle, if you let recursive code get out of control, it could use up all the memory on the underlying server. I decided to try this out on Oracle 12:

SQL> create or replace procedure recursion is
  2  begin
  3  recursion();
  4  end;
  5  /
 
Procedure created.
 
SQL> exec recursion();

While this was running, I found I could still use the machine so I took a look in the alert log and saw the following errors at the end:

Thu Feb 12 17:43:34 2015
Errors in file C:\APP\ADMINISTRATOR\diag\rdbms\orcl1\orcl1\trace\orcl1_ora_2796.trc  (incident=19267):
ORA-04036: PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT
Incident details in: C:\APP\ADMINISTRATOR\diag\rdbms\orcl1\orcl1\incident\incdir_19267\orcl1_ora_2796_i19267.trc
Errors in file C:\APP\ADMINISTRATOR\diag\rdbms\orcl1\orcl1\trace\orcl1_ora_2796.trc  (incident=19268):
ORA-04036: PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT
ORA-04036: PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT
Incident details in: C:\APP\ADMINISTRATOR\diag\rdbms\orcl1\orcl1\incident\incdir_19268\orcl1_ora_2796_i19268.trc

When I looked in V$SESSION_EVENT, I saw that there had been a brief wait on the acknowledge over PGA limit event:

SQL> l
  1  select event, time_waited/100
  2  from v$session_event
  3* where sid = 11
SQL> /
 
EVENT                          TIME_WAITED/100
------------------------------ ---------------
acknowledge over PGA limit                7.05
Disk file operations I/O                     0
log buffer space                             0
SQL*Net message to client                    0
SQL*Net message from client             116.29
SQL*Net break/reset to client                0
 
6 rows selected.
 
SQL>

After this, the session was killed:
 
SQL> select status from v$session where sid = 11;
 
STATUS
--------
KILLED
 
SQL>

… and there was a message to this effect in the alert log:

Thu Feb 12 17:52:59 2015
Errors in file C:\APP\ADMINISTRATOR\diag\rdbms\orcl1\orcl1\incident\incdir_19267\orcl1_ora_2796_i19267.trc:
ORA-00028: your session has been killed
ORA-04036: PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT

The only problem I could see was that no error message was returned to the session running the recursion.

As an extra test, I used SYS to run the recursive procedure:

C:\Users\Administrator>sqlplus / as sysdba
 
SQL*Plus: Release 12.1.0.1.0 Production on Fri Feb 13 09:02:36 2015
 
Copyright (c) 1982, 2013, Oracle.  All rights reserved.
 
Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
 
SQL> exec system.recursion();

This wrote more serious messages to the alert log:

Fri Feb 13 09:04:39 2015
PGA_AGGREGATE_LIMIT has been exceeded but some processes using the most PGA
memory are not eligible to receive ORA-4036 interrupts.  Further occurrences
of this condition will be written to the trace file of the CKPT process.

The session remained ACTIVE and V$SESSION_EVENT did not know what it was waiting for:

SQL> select sid from v$session
  2  where username = 'SYS';
 
       SID
----------
       237
 
SQL> select status from v$session
  2  where sid = 237;
 
STATUS
--------
ACTIVE
 
SQL> select event, time_waited/100
  2  from v$session_event
  3  where sid = 237
  4  /
 
EVENT                                    TIME_WAITED/100
---------------------------------------- ---------------
Disk file operations I/O                               0
db file sequential read                              .09
SQL*Net message to client                              0
SQL*Net message from client                       101.92
 
SQL>

Thursday, March 26, 2015

RECOVER DATABASE TEST

I logged into an Oracle 12.1 database and ran the ALTER DATABASE BEGIN BACKUP command. This told Oracle I was about to start a hot backup:

C:\Users\Administrator>sqlplus / as sysdba
 
SQL*Plus: Release 12.1.0.1.0 Production on Thu Mar 26 10:08:51 2015
 
Copyright (c) 1982, 2013, Oracle.  All rights reserved.
 
Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options
 
SQL> alter database begin backup
  2  /
 
Database altered.
 
SQL>

I copied one of the database’s datafiles somewhere safe:

C:\app\Administrator\oradata\ORCL1\DATAFILE>copy O1_MF_USERS_BDGW2LNZ_.DBF z:\data\oracle_backup
        1 file(s) copied.
 
C:\app\Administrator\oradata\ORCL1\DATAFILE>

Then I used the ALTER DATABASE END BACKUP command to tell Oracle the hot backup was finished and closed the database:

SQL> alter database end backup;
 
Database altered.
 
SQL> shutdown
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL>

I deleted the datafile I had backed up:

C:\app\Administrator\oradata\ORCL1\DATAFILE>del O1_MF_USERS_BDGW2LNZ_.DBF
 
C:\app\Administrator\oradata\ORCL1\DATAFILE>

Then I restored it from the backup which I had made earlier:

Z:\Data\Oracle_Backup>copy O1_MF_USERS_BDGW2LNZ_.DBF C:\app\Administrator\oradata\ORCL1\DATAFILE
        1 file(s) copied.
 
Z:\Data\Oracle_Backup>

I mounted the database:

Z:\Data\Oracle_Backup>sqlplus / as sysdba
 
SQL*Plus: Release 12.1.0.1.0 Production on Wed Mar 18 15:50:55 2015
 
Copyright (c) 1982, 2013, Oracle.  All rights reserved.
 
Connected to an idle instance.
 
SQL> startup mount
ORACLE instance started.
 
Total System Global Area 1720328192 bytes
Fixed Size                  2403496 bytes
Variable Size            1023411032 bytes
Database Buffers          687865856 bytes
Redo Buffers                6647808 bytes
Database mounted.
SQL>

I read in some Oracle documentation that if you added the word TEST after a RECOVER command, you could test the recovery you were about to attempt. I decided to try it out but the messages it produced did not seem to tell me whether the recovery would succeed or fail:

SQL> recover database test
ORA-10574: Test recovery did not corrupt any data block
ORA-10573: Test recovery tested redo from change 11524259 to 11525796
ORA-10572: Test recovery canceled due to errors
ORA-10585: Test recovery can not apply redo that may modify control file
 
SQL>

I decided to give it a try anyway and it worked without problem:

SQL> recover database
Media recovery complete.
SQL> alter database open
  2  /
 
Database altered.
 
SQL>

Wednesday, March 25, 2015

A Simple Example With V$BACKUP

I tested this in an Oracle 12.1 database. The V$BACKUP view tells you if a datafile is in hot backup mode. I started off with none of the datafiles in hot backup mode so they were all shown as NOT ACTIVE:

SQL> select file#, status from v$backup
  2  /
 
     FILE# STATUS
---------- ------------------
         1 NOT ACTIVE
         2 NOT ACTIVE
         3 NOT ACTIVE
         5 NOT ACTIVE
         6 NOT ACTIVE
 
SQL>

I put the USERS tablespace into hot backup mode and its datafile changed to ACTIVE in V$BACKUP until I took the tablespace out of hot backup mode:

SQL> alter tablespace users begin backup
  2  /
 
Tablespace altered.
 
SQL> select file_id from dba_data_files
  2  where tablespace_name = 'USERS'
  3  /
 
   FILE_ID
----------
         6
 
SQL> select file#, status from v$backup
  2  /
 
     FILE# STATUS
---------- ------------------
         1 NOT ACTIVE
         2 NOT ACTIVE
         3 NOT ACTIVE
         5 NOT ACTIVE
         6 ACTIVE
 
SQL> alter tablespace users end backup
  2  /
 
Tablespace altered.
 
SQL> select file#, status from v$backup
  2  /
 
     FILE# STATUS
---------- ------------------
         1 NOT ACTIVE
         2 NOT ACTIVE
         3 NOT ACTIVE
         5 NOT ACTIVE
         6 NOT ACTIVE
 
SQL>

… and when I put the whole database into hot backup mode, all the datafiles were shown as ACTIVE:

SQL> alter database begin backup
  2  /
 
Database altered.
 
SQL> select file#, status from v$backup
  2  /
 
     FILE# STATUS
---------- ------------------
         1 ACTIVE
         2 ACTIVE
         3 ACTIVE
         5 ACTIVE
         6 ACTIVE
 
SQL> alter database end backup
  2  /
 
Database altered.
 
SQL> select file#, status from v$backup
  2  /
 
     FILE# STATUS
---------- ------------------
         1 NOT ACTIVE
         2 NOT ACTIVE
         3 NOT ACTIVE
         5 NOT ACTIVE
         6 NOT ACTIVE
 
SQL>

Saturday, March 21, 2015

Re-Creating Datafiles When Backups Are Unavailable

I found an old copy of the Oracle 9i User-Managed Backup and Recovery Guide and read the following:
 
If a datafile is damaged and no backup of the file is available, then you can still recover the datafile if:
 
·         All archived log files written after the creation of the original datafile are available
·         The control file contains the name of the damaged file (that is, the control file is current, or is a backup taken after the damaged datafile was added to the database)
 
I decided to try this out in an Oracle 12.1 database. First I checked that the database was in ARCHIVELOG mode:

SQL> select log_mode from v$database
  2  /
 
LOG_MODE
------------
ARCHIVELOG
 
SQL>

I created a tablespace called ANDREW:

SQL> create tablespace andrew
  2  datafile 'C:\APP\ADMINISTRATOR\ORADATA\ORCL1\DATAFILE\ANDREW.DBF'
  3  size 20m
  4  /
 
Tablespace created.
 
SQL>

I created a table in the tablespace:

SQL> l
  1  create table marker
  2  tablespace andrew as
  3  select 'Andrew was here again' message
  4* from dual
SQL> /
 
Table created.
 
SQL>

I closed the database:

SQL> shutdown
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL>

I deleted the tablespace’s datafile:

C:\app\Administrator\oradata\ORCL1\DATAFILE>dir
Volume in drive C has no label.
Volume Serial Number is 269C-9AD9
 
Directory of C:\app\Administrator\oradata\ORCL1\DATAFILE
 
19/03/2015  18:32    <DIR>          .
19/03/2015  18:32    <DIR>          ..
19/03/2015  18:39        20,979,712 ANDREW.DBF
19/03/2015  18:39     3,722,452,992 O1_MF_SYSAUX_BDGVW9OT_.DBF
19/03/2015  18:39       964,698,112 O1_MF_SYSTEM_BDGVZ93W_.DBF
19/03/2015  11:08     1,906,319,360 O1_MF_TEMP_BDGW88KG_.TMP
19/03/2015  18:39     1,378,885,632 O1_MF_UNDOTBS1_BDGW2MY6_.DBF
19/03/2015  18:39     4,650,442,752 O1_MF_USERS_BDGW2LNZ_.DBF
               6 File(s) 12,643,778,560 bytes
               2 Dir(s)   5,940,617,216 bytes free
 
C:\app\Administrator\oradata\ORCL1\DATAFILE>del andrew.dbf
 
C:\app\Administrator\oradata\ORCL1\DATAFILE>dir
Volume in drive C has no label.
Volume Serial Number is 269C-9AD9
 
Directory of C:\app\Administrator\oradata\ORCL1\DATAFILE
 
19/03/2015  18:42    <DIR>          .
19/03/2015  18:42    <DIR>          ..
19/03/2015  18:39     3,722,452,992 O1_MF_SYSAUX_BDGVW9OT_.DBF
19/03/2015  18:39       964,698,112 O1_MF_SYSTEM_BDGVZ93W_.DBF
19/03/2015  11:08     1,906,319,360 O1_MF_TEMP_BDGW88KG_.TMP
19/03/2015  18:39     1,378,885,632 O1_MF_UNDOTBS1_BDGW2MY6_.DBF
19/03/2015  18:39     4,650,442,752 O1_MF_USERS_BDGW2LNZ_.DBF
               5 File(s) 12,622,798,848 bytes
               2 Dir(s)   5,961,596,928 bytes free
 
C:\app\Administrator\oradata\ORCL1\DATAFILE>

I tried to open the database:

C:\app\Administrator\oradata\ORCL1\DATAFILE>sqlplus / as sysdba
 
SQL*Plus: Release 12.1.0.1.0 Production on Thu Mar 19 18:43:02 2015
 
Copyright (c) 1982, 2013, Oracle.  All rights reserved.
 
Connected to an idle instance.
 
SQL> startup
ORACLE instance started.
 
Total System Global Area 1720328192 bytes
Fixed Size                  2403496 bytes
Variable Size            1023411032 bytes
Database Buffers          687865856 bytes
Redo Buffers                6647808 bytes
Database mounted.
ORA-01157: cannot identify/lock data file 2 - see DBWR trace file
ORA-01110: data file 2:
'C:\APP\ADMINISTRATOR\ORADATA\ORCL1\DATAFILE\ANDREW.DBF'
 
SQL>
 
I created the missing datafile:

SQL> alter database create datafile
  2  'C:\APP\ADMINISTRATOR\ORADATA\ORCL1\DATAFILE\ANDREW.DBF'
  3  /
 
Database altered.
 
SQL>

I recovered the datafile:

SQL> recover datafile 'C:\APP\ADMINISTRATOR\ORADATA\ORCL1\DATAFILE\ANDREW.DBF'
Media recovery complete.
SQL>

I looked for the MARKER table but realized that the database was not open:

SQL> select * from marker
  2  /
select * from marker
              *
ERROR at line 1:
ORA-01219: database or pluggable database not open: queries allowed on fixed
tables or views only
 
SQL>
 
I opened the database:

SQL> alter database open
  2  /
 
Database altered.
 
SQL>

… and the MARKER table was there as before:

SQL> select * from marker
  2  /
 
MESSAGE
---------------------
Andrew was here again
 
SQL> select tablespace_name
  2  from dba_tables
  3  where table_name = 'MARKER'
  4  /
 
TABLESPACE_NAME
------------------------------
ANDREW
 
SQL>
 
The Oracle guide went on to say:
 
Note: You cannot re-create any of the datafiles for the SYSTEM tablespace by using the CREATE DATAFILE clause of the ALTER DATABASE statement because the necessary redo data is not available.
 
I will see what happens if you try to do this in a future post.