Wednesday, September 1, 2010

No Archive Mode

Backup and Recovery : Part 2

Backup Strategies
-------------------
Have you ever been in a state of confusion with the various backing up strategies like cold/hot or archive/no archive ?
At-least that was the case with me always . Very lately i found out that the main distinction is not between hot or cold but it is between archive mode and non archive mode .

You can check the mode in which your database is running :-
SQL> select log_mode from v$database;

LOG_MODE
------------
NOARCHIVELOG

SQL> archive log list
Database log mode              No Archive Mode
Automatic archival             Disabled
Archive destination            USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence     1
Current log sequence           1


My database here is running in non-archive mode. And hence , we will deal with non-archive mode first.

Now coming to hot/cold backup ; hot backup is when you take the backup when your database is online and cold is when your database is offline i.e. properly shutdown . Hot backup is not possible in case of nonarchive mode .A proper shutdown of the database is required for nonarchive backup , even shutdown abort brings your system in an inconsistent state , hence shouldn't be used for cold backup.


NO-ARCHIVE MODE

What to Backup ?
-------------------

If you are not sure about the location of the datafiles and the control files , check the same by using this :-
SQL>  select name from v$datafile;

NAME
--------------------------------------------------------------------------------
/scratch/aime1/app/aime1/oradata/orcl/system01.dbf
/scratch/aime1/app/aime1/oradata/orcl/sysaux01.dbf
/scratch/aime1/app/aime1/oradata/orcl/undotbs01.dbf
/scratch/aime1/app/aime1/oradata/orcl/users01.dbf
/scratch/aime1/app/aime1/oradata/orcl/example01.dbf

SQL> show parameter control_files;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
control_files                        string      /scratch/aime1/app/aime1/orada
ta/orcl/control01.ctl, /scratc
h/aime1/app/aime1/flash_recove
ry_area/orcl/control02.ctl


Redo log files should not be backed up in no-archive mode since they are continuously over-written without archiving.

How to take Backup ?
---------------------

Shutdown the database properly forcing a checkpoint in the files.
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.


Go to the terminal and make a backup of all the files in another folder :-

bash-3.00$ pwd
/scratch/aime1/app/aime1/oradata/orcl
bash-3.00$ ls
control01.ctl redo01.log redo03.log system01.dbf undotbs01.dbf
example01.dbf redo02.log sysaux01.dbf temp01.dbf users01.dbf
bash-3.00$ ls *.dbf
example01.dbf system01.dbf undotbs01.dbf
sysaux01.dbf temp01.dbf users01.dbf
bash-3.00$ cp *.dbf ~/app/aime1/Backup/
bash-3.00$ cd control01.ctl ~/app/aime1/Backup/
bash: cd: control01.ctl: Not a directory
bash-3.00$ cp control01.ctl ~/app/aime1/Backup/
bash-3.00$ cd ~/app/aime1/Backup/
bash-3.00$ ls
control01.ctl sysaux01.dbf temp01.dbf users01.dbf
example01.dbf system01.dbf undotbs01.dbf

Why to recover?
------------------------------

Now go back to the sqlplus and start the database again

To check the default tablespace for a user , use
SQL> select USERNAME,DEFAULT_TABLESPACE from dba_users where username ='SCOTT';

USERNAME                       DEFAULT_TABLESPACE
------------------------------ ------------------------------
SCOTT                          USERS


SQL> create table test(a number);

Table created

SQL> insert into test values(1);

1 row created.

Hence the dbf file for the users tablespace i.e. USERS01.dbf is modified . Now perform a shutodwn again.

How to Recover?
----------------------

If we assume now that the dbf file for the users tablespace is lost/ corrupted because of some problem , the question is how do we recover it now with the available backup that we have.
There are different possibilities and going stepwise :-

STEP 1:- Copy the dbf file from the backup location to the original location.

First take a backup of the original dbf file (Best practice) and then copy the backup dbf file.

bash-3.00$ pwd
/scratch/aime1/app/aime1/Backup
bash-3.00$ cd ../oradata/orcl/
bash-3.00$ cp users01.dbf users01.dbf.bak
bash-3.00$ cp ~/app/aime1/Backup/users01.dbf users01.dbf

Now try to start the database.
SQL> startup;
ORACLE instance started.

Total System Global Area 2042241024 bytes
Fixed Size                  1337548 bytes
Variable Size            1056966452 bytes
Database Buffers          973078528 bytes
Redo Buffers               10858496 bytes
Database mounted.
ORA-01113: file 4 needs media recovery
ORA-01110: data file 4: '/scratch/aime1/app/aime1/oradata/orcl/users01.dbf'

It throws an error saying "Media Recovery is needed" . The database state at this point is "MOUNTED" but it could not be started.

Now if check the checkpoint number for the datafiles and the control files :-
SQL> select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 01-SEP-10            1419740
2 01-SEP-10            1419740
3 01-SEP-10            1419740
4 01-SEP-10            1416309
5 01-SEP-10            1419740

SQL> select CHECKPOINT_CHANGE# from v$database;

CHECKPOINT_CHANGE#
------------------
1419740

The datafile #4 (Users01.dbf) is behind in SCN number than the other files and the control files.

If we try to recover database by running this ,
SQL> recover database
Media recovery complete.

It says that " Media Recovery is completed" .
Checking the alert_SID.log file :-
Contents:-
ALTER DATABASE RECOVER database
Media Recovery Start
started logmerger process
Parallel Media Recovery started with 2 slaves
Wed Sep 01 02:30:24 2010
Recovery of Online Redo Log: Thread 1 Group 1 Seq 40 Reading mem 0
Mem# 0: /scratch/aime1/app/aime1/oradata/orcl/redo01.log
Recovery of Online Redo Log: Thread 1 Group 2 Seq 41 Reading mem 0
Mem# 0: /scratch/aime1/app/aime1/oradata/orcl/redo02.log
Media Recovery Complete (orcl)
Completed: ALTER DATABASE RECOVER database

It shows that redo log files were used for the recovery of the database . That was possible because there wasnt much log switch happened after the backup , hence the SCN number was present in the log files for the recovery .
SQL> alter database open;

Database altered.

SQL>  select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 01-SEP-10            1419743
2 01-SEP-10            1419743
3 01-SEP-10            1419743
4 01-SEP-10            1419743
5 01-SEP-10            1419743

SQL> select * from SCOTT.test;

A
----------
1

Suppose that there were many log switches after we took of cold backup of all the files.
SQL> alter system switch logfile;

System altered.

SQL> alter system switch logfile;

System altered.

SQL> alter system switch logfile;

System altered.

Now in this case , if we try to run "Recover Database" then
QL> recover database;
ORA-00279: change 1416309 generated at 09/01/2010 01:48:54 needed for thread 1
ORA-00289: suggestion :
/scratch/aime1/app/aime1/flash_recovery_area/ORCL/archivelog/2010_09_01/o1_mf_1_
40_%u_.arc
ORA-00280: change 1416309 for thread 1 is in sequence #40


Specify log: {=suggested | filename | AUTO | CANCEL}

ORA-00308: cannot open archived log
'/scratch/aime1/app/aime1/flash_recovery_area/ORCL/archivelog/2010_09_01/o1_mf_1
_40_%u_.arc'
ORA-27037: unable to obtain file status
Linux Error: 2: No such file or directory
Additional information: 3

Now media recovery is not possible in this case .

It asks us about the location of the archived log files but our database is running in noarchivelog mode , hence we dnt have any archived logs. Hence, it gives an error that media recovery is not possible.
In this case, goto STEP 2.


STEP 2:- Using Backup Control File

Copy the backup control file to the original location .

bash-3.00$ cp control01.ctl control01.ctl.bak
bash-3.00$ cp ~/app/aime1/Backup/control01.ctl control01.ctl

Now try to start the database
SQL> startup;
ORACLE instance started.

Total System Global Area 2042241024 bytes
Fixed Size                  1337548 bytes
Variable Size            1056966452 bytes
Database Buffers          973078528 bytes
Redo Buffers               10858496 bytes
ORA-00214: control file
'/scratch/aime1/app/aime1/flash_recovery_area/orcl/control02.ctl' version 3557
inconsistent with file '/scratch/aime1/app/aime1/oradata/orcl/control01.ctl'
version 3503

It gives an error of the version mismatch between both the control files . Hence we need to copy the backup control file to other location as well.

bash-3.00$ cp ~/app/aime1/Backup/control01.ctl control01.ctl
bash-3.00$ cp /scratch/aime1/app/aime1/oradata/orcl/control01.ctl /scratch/aime1/app/aime1/flash_recovery_area/orcl/control02.ctl

Again starting the database :
SQL> startup;
ORACLE instance started.

Total System Global Area 2042241024 bytes
Fixed Size                  1337548 bytes
Variable Size            1056966452 bytes
Database Buffers          973078528 bytes
Redo Buffers               10858496 bytes
Database mounted.
ORA-01122: database file 1 failed verification check
ORA-01110: data file 1: '/scratch/aime1/app/aime1/oradata/orcl/system01.dbf'
ORA-01207: file is more recent than control file - old control file

SQL> select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 01-SEP-10            1423110
2 01-SEP-10            1423110
3 01-SEP-10            1423110
4 01-SEP-10            1416309
5 01-SEP-10            1423110

SQL> select CHECKPOINT_CHANGE# from v$database;

CHECKPOINT_CHANGE#
------------------
1416309

Checkpoint number in the control file is less than those in other dbf files .
Now if we try to recover saying "using backup controlfile" , it gives an error "RECOVER succeeded but OPEN RESETLOGS would get error below" :-

SQL> RECOVER DATABASE USING BACKUP CONTROLFILE UNTIL CANCEL
ORA-00279: change 1416309 generated at 09/01/2010 01:48:54 needed for thread 1
ORA-00289: suggestion :
/scratch/aime1/app/aime1/flash_recovery_area/ORCL/archivelog/2010_09_01/o1_mf_1_
40_%u_.arc
ORA-00280: change 1416309 for thread 1 is in sequence #40

Specify log: {=suggested | filename | AUTO | CANCEL}

ORA-00308: cannot open archived log
'/scratch/aime1/app/aime1/flash_recovery_area/ORCL/archivelog/2010_09_01/o1_mf_1
_40_%u_.arc'
ORA-27037: unable to obtain file status
Linux Error: 2: No such file or directory
Additional information: 3

ORA-10879: error signaled in parallel recovery slave
ORA-01547: warning: RECOVER succeeded but OPEN RESETLOGS would get error below
ORA-01152: file 1 was not restored from a sufficiently old backup
ORA-01110: data file 1: '/scratch/aime1/app/aime1/oradata/orcl/system01.dbf'

Trying to open the database :-
SQL> alter database open;
alter database open
*
ERROR at line 1:
ORA-01589: must use RESETLOGS or NORESETLOGS option for database open

SQL> alter database open noresetlogs;
alter database open noresetlogs
*
ERROR at line 1:
ORA-01588: must use RESETLOGS option for database open

SQL> alter database open resetlogs;
alter database open resetlogs
*
ERROR at line 1:
ORA-01152: file 1 was not restored from a sufficiently old backup
ORA-01110: data file 1: '/scratch/aime1/app/aime1/oradata/orcl/system01.dbf'


Hence its not possible to do this without the redo log files .
In this case , go to STEP 3

STEP 3
: Copy all the files

Copy all the backup dbf files and ctl file to the original location

bash-3.00$ cp ~/app/aime1/Backup/*.dbf .

Now try to open the database with resetlogs :-
SQL> alter database open resetlogs;

Database altered.

ALert_SID. log file contents :-

alter database open resetlogs
RESETLOGS after incomplete recovery UNTIL CHANGE 1416309
Resetting resetlogs activation ID 1255868088 (0x4adb06b8)
Wed Sep 01 03:27:09 2010

Now check the checkpoint number :-

SQL> select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 01-SEP-10            1416313
2 01-SEP-10            1416313
3 01-SEP-10            1416313
4 01-SEP-10            1416313
5 01-SEP-10            1416313

SQL> select CHECKPOINT_CHANGE# from v$database;

CHECKPOINT_CHANGE#
------------------
1416313


All the files have reached to the same checkpoint number .

If we try to access the tets table now , it gives an error that it doesnt exist .
SQL> select * from Scott.test
2  ;
select * from Scott.test
*
ERROR at line 1:
ORA-00942: table or view does not exist

This error comes because our database is restored to the time when last backup was taken and that time test table wasn't created.

CONCLUSION :-
------------------

From the above scenario , we can conclude that the media recovery is not possible in case of no-archive log, only instance recovery can be done. That also, our instance is recovered back to the time when last backup was taken , and all the changes made to the database after that are lost. Archiving redo logs i.e. archive mode is solution to this.

Friday, August 27, 2010

REDO Log and Checkpoint

I was reading about the data backup and recovery in Oracle DB and in the end , was left with all confusion. So finally decided to start from reading checkpoint/logfile concepts so that it helps in better understanding .

So you can consider this post as :-
Backup and Recovery : Concepts Part 1

REDO LOGFILE
-----------------
The Oracle server maintains the redo Oracle log files to minimize the loss of data in the Database in case of an uncontrolled shutdown.

Online redo Oracle log files are filled with redo records. A redo record, also called a redo entry, is made up of a group of change vectors, each of which is a description of a change made to a single block in the database.

For example, if you change a employee name in an employee table, you generate a redo record containing change vectors that describe changes to the data segment block for the table, the rollback segment data block, and the transaction table of the rollback segments.

Two views play an important part here namely , v$log and v$logfile.

v$logfile can be used to find the path of the redo log or their type (online/standby(used for standby database))
For more information on standby redo logs :-
http://www.pythian.com/news/581/oracle-standby-redo-logs/

 
SQL> select group#,type,member from v$logfile;

GROUP# TYPE MEMBER
--------------------------------------------------------------------------------
3 ONLINE /scratch/aime1/app/aime1/oradata/orcl/redo03.log
2 ONLINE /scratch/aime1/app/aime1/oradata/orcl/redo02.log
1 ONLINE /scratch/aime1/app/aime1/oradata/orcl/redo01.log


v$log can be used to find out if your redo logs are archived or not with archived column . And also to check the status of the the log files . There are different log status , few of the important ones are:-

1. UNUSED - Online redo log has never been written to. This is the state of a redo log that was just added, or just after a RESETLOGS, when it is not the current redo log.
2. CURRENT - Current redo log. This implies that the redo log is active. The redo log could be open or closed.
3. ACTIVE - Log is active but is not the current log. It is needed for crash recovery. It may be in use for block recovery. It may or may not be archived.
4. INACTIVE - Log is no longer needed for instance recovery. It may be in use for media recovery. It might or might not be archived.
5. INVALIDATED - Archived the current redo log without a log switch.

 
SQL> SELECT group#, sequence#, members, archived, status FROM v$log;

GROUP# SEQUENCE# MEMBERS ARC STATUS
---------- ---------- ---------- --- ----------------
1 7 1 NO CURRENT
2 5 1 NO INACTIVE
3 6 1 NO INACTIVE


Also to check which archivelog/no archivelog mode , we can use
 
SQL> select log_mode from v$database;

LOG_MODE
------------
NOARCHIVELOG

-------------------------------------------------------------------------------------

CHECKPOINT
----------------

A checkpoint performs the following three operations:

1. Every dirty block in the buffer cache is written to the data files. That is, it(DBWR) synchronizes the datablocks in the buffer cache with the datafiles on disk.
2. The latest SCN is written (updated) into the datafile header.
3. The latest SCN is also written to the controlfiles.

Every modification in the database (for example, an update) is given an unique system change number SCN, which is, therefore, an ever increasing integer. The latest SCN is immediately recorded in the controlfile. The modifications are logged in the online redo log by the log writer LGWR, but not necessarily in the datafiles.

v$datafile_header can be used to find out the checkpoint number in the datafiles .

 
SQL> select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 27-AUG-10 829278
2 27-AUG-10 829278
3 27-AUG-10 829278
4 27-AUG-10 829278
5 27-AUG-10 829278


Latest checkpoint number can be found with the help of v$database

 
SQL> select CHECKPOINT_CHANGE# from v$database;

CHECKPOINT_CHANGE#
------------------
829278

If the control file is a backup file , checkpoint number in the file can be found with :-
 
SQL> select CONTROLFILE_CHANGE# from v$database;

CONTROLFILE_CHANGE#
-------------------
830797

-------------------------------------------------------------------------------------

REDO Log and Checkpoint
---------------------------

Now , "alter system switch logfile " forces a redo log switch to happen . A log switch also occurs when one online redo log has been filled and the next online redo log is going to be filled.

A log switch always triggers a checkpoint (that's what is written at maximum places) but if you see this carefully .

 
SQL> select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 27-AUG-10 831582
2 27-AUG-10 831582
3 27-AUG-10 831582
4 27-AUG-10 831582
5 27-AUG-10 831582

SQL> select checkpoint_change# from v$database;

CHECKPOINT_CHANGE#
------------------
831582

SQL> SQL> SELECT group#, sequence#, members, archived, status FROM v$log;

GROUP# SEQUENCE# MEMBERS ARC STATUS
---------- ---------- ---------- --- ----------------
1 13 1 NO INACTIVE
2 14 1 NO CURRENT
3 12 1 NO INACTIVE

SQL> alter system switch logfile;

System altered.

SQL> SELECT group#, sequence#, members, archived, status FROM v$log;

GROUP# SEQUENCE# MEMBERS ARC STATUS
---------- ---------- ---------- --- ----------------
1 13 1 NO INACTIVE
2 14 1 NO ACTIVE
3 15 1 NO CURRENT

SQL> select checkpoint_change# from v$database;

CHECKPOINT_CHANGE#
------------------
831582

SQL> select FILE#, CHECKPOINT_TIME, CHECKPOINT_CHANGE# from V$DATAFILE_HEADER;

FILE# CHECKPOIN CHECKPOINT_CHANGE#
---------- --------- ------------------
1 27-AUG-10 831582
2 27-AUG-10 831582
3 27-AUG-10 831582
4 27-AUG-10 831582
5 27-AUG-10 831582


There is no change in the checkpoint . Checkpointing in case of log switch happens if there are dirty buffers to be written to the datafile or in other words , SCN in the datafile header and in the control file don't match . Here since they were same , no checkpointing occurred even though log was switched.

Also , if we do a checkpointing , log switch doesn't happen but triggering a checkpoint brings the log files in "INACTIVE" state since they are no longer needed in instance recovery (may be needed in the media recovery) ( as it is written on the datafiles).

 
SQL> SELECT group#, sequence#, members, archived, status FROM v$log;

GROUP# SEQUENCE# MEMBERS ARC STATUS
---------- ---------- ---------- --- ----------------
1 13 1 NO CURRENT
2 11 1 NO INACTIVE
3 12 1 NO INACTIVE

SQL> alter system switch logfile;

System altered.

SQL> SELECT group#, sequence#, members, archived, status FROM v$log;

GROUP# SEQUENCE# MEMBERS ARC STATUS
---------- ---------- ---------- --- ----------------
1 13 1 NO ACTIVE
2 14 1 NO CURRENT
3 12 1 NO INACTIVE

SQL> alter system checkpoint;

System altered.

SQL> SELECT group#, sequence#, members, archived, status FROM v$log;

GROUP# SEQUENCE# MEMBERS ARC STATUS
---------- ---------- ---------- --- ----------------
1 13 1 NO INACTIVE
2 14 1 NO CURRENT
3 12 1 NO INACTIVE

-------------------------------------------------------------------------------------

Monday, April 5, 2010

Query Processing and Parsing

Queries in the Oracle need to be broken down into its sub-components and various checks needs to be performed on them before it can actually be executed.
The first phase of parsing a query includes Syntax check followed by Semantic check. Syntax check basically deals with the array of the SQL Grammar i.e. whether the statement/query written exists in the SQL Dictionary or is correct according to the grammar of the SQL Language while Semantic check checks for the existence of the object referred in the query i.e. Semantic check is, in short, the object check.

SQL> select * form tab;
select * form tab
*
ERROR at line 1:
ORA-00923: FROM keyword not found where expected

Here what it returns is the expression saying, "FROM keyword not found " ... That means something is wrong with the syntax of the statement i.e. the structure of the query is not matching with what is expected. So, it failed at the syntax check ...

Now in semantic check, if the syntax is correct and the objects referred in the query are correct; then it generates the output otherwise not.
By the correctness the object, comes various considerations like privileges, existence etc. But the main point remains the same; the object should be visible to the user and the user should have necessary privileges on the object referred.

SQL> select * from tabl;
select * from tabl
*
ERROR at line 1:
ORA-00942: table or view does not exist

Semantic check failed since table doesn't exist even though the syntax of the query is correct.


After both the checks are done, Oracle checks if the exactly same query has been processed before i.e. if the work has already been done before. Shared pool, component of SGA (Shared/System Global Area) plays an important part here ... The SGA is a chunk of memory that is allocated by an Oracle Instance (during the no mount stage) and is shared among Oracle processes. The shared pool is used for objects that are shared among all users. Shared Pool has two important components: - Library Cache and Data Dictionary Cache. Data Dictionary cache stores part of the data dictionary because Oracle has to query the data dictionary very often while library cache is further divided into Shared SQL Area, PL/SQL Procedures and Control Structures (Latches and Locks) which stores the SQL text and the execution plan for the query.

Now if the query has been processed before and if it is found in library cache of SGA, then area called cursor area is already allocated in the library cache and execution plan exists there and thus we don’t need to perform the steps like Query Transformation, Plan generation again saving us lot of time ... This is what we called as "SOFT PARSE".

But if the query isn't there in library cache, then what we do, we call it as "HARD PARSE". In short, the steps that are there are: -
1. Oracle unpins the library cache latch and pin the shared pool latch.
2. Then it performs the query transformation steps (Query rewrite, bind variables etc)
3. After the query transformation, Oracle estimates the cost of the query in terms of I/O, Memory and CPU
4. And based on the cost, it generates multiple plans to execute the query and picks the most optimized plan and executes the query.

We can check for the execution plan selected for a query by using set autot command .It displays a report on the execution of successful SQL DML statements (such as SELECT, INSERT, UPDATE, DELETE or MERGE). The report can include execution statistics and the query execution path.

Syntax: -
SET AUTOT[RACE] {ON | OFF | TRACE[ONLY]} [EXP[LAIN]] [STAT[ISTICS]]

OFF does not display a trace report. ON displays a trace report. TRACEONLY displays a trace report, but does not print query data, if any. EXPLAIN shows the query execution path by performing an EXPLAIN PLAN. STATISTICS displays SQL statement statistics.

SQL> set autot on exp stat;
SQL> /

A
----------
1


Execution Plan
----------------------------------------------------------
Plan hash value: 1357081020

------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time
------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |    13 |     2   (0)| 00:00:01
|   1 |  TABLE ACCESS FULL| TEST |     1 |    13 |     2   (0)| 00:00:01
------------------------------------------------------------------------

Note
-----
- dynamic sampling used for this statement


Statistics
----------------------------------------------------------
0  recursive calls
0  db block gets
3  consistent gets
0  physical reads
0  redo size
415  bytes sent via SQL*Net to client
416  bytes received via SQL*Net from client
2  SQL*Net roundtrips to/from client
0  sorts (memory)
0  sorts (disk)
1  rows processed

Execution Plan gives us the cost and the rows etc while statistics gives us the more physical reads and blocks information.


There is another type of parsing also, called as "SOFTER SOFT PARSE". It makes use of the initialization parameter session_cached_cursors. If this parameter is set to some value, then in that case; Oracle takes you query, looks into the session cursor cache, picks up the cursor and reuses it. This involves lesser work, even lesser than SOFT Parse.

SQL> show parameter session_cached;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ---------------------------
session_cached_cursors               integer     50

If it is enabled, then two parameters play an important part from v$statname :- 

SQL> select a.name, b.value
2  from v$statname a, v$mystat b
3  where a.statistic# = b.statistic#
4  and lower(a.name) like '%cursor ca%';

NAME                                                                  VALUE
---------------------------------------------------------------- ----------
session cursor cache hits                                                 0
session cursor cache count                                              0

So when a query is parsed for three times and caching of cursors is enabled, it increases the cursor cache count and caches the cursor ... And from next time onwards, uses that cursor increasing the cache hits count.


SQL> select a.name, b.value
2  from v$statname a, v$mystat b
3  where a.statistic# = b.statistic#
4  and lower(a.name) like '%cursor ca%';

NAME                                                                  VALUE
---------------------------------------------------------------- ----------
session cursor cache hits                                                 0
session cursor cache count                                              1

SQL> select * from test;

A
----------
1

SQL> select a.name, b.value
2  from v$statname a, v$mystat b
3  where a.statistic# = b.statistic#
4  and lower(a.name) like '%cursor ca%';

NAME                                                                  VALUE
---------------------------------------------------------------- ----------
session cursor cache hits                                                 1
session cursor cache count                                              3

( Cache Count increased) 


SQL> select * from test;

A
----------
1

SQL> select a.name, b.value
2  from v$statname a, v$mystat b
3  where a.statistic# = b.statistic#
4  and lower(a.name) like '%cursor ca%';

NAME                                                                  VALUE
---------------------------------------------------------------- ----------
session cursor cache hits                                                 3
session cursor cache count                                              3


(Cache Hit increasing ... It increased twice, once for test query and another to display the statistics)...



So, in short, it has three types of parsing: -

1. HARD Parse: - First time query is being executed, parse it (syntax check, semantic check), hash it, look in the shared pool, not present, perform transformations, optimize it etc....
2. SOFT Parse: - Executed before, parse it, hash it, look in the shared pool, present, use it.
3. SOFTER soft Parse: - Look into session cursor cache, found, uses it. (But only if session_cached_cursors set to some value).

In database system, the ratio of SOFT Parse/HARD Parse should be very high since it implies the same query was reused again and again and less work was done.

Friday, April 2, 2010

RECYCLE BIN IN DATABASE

Introduction: -

We always hear the word 'Recycle Bin' in Windows but I never knew that such a word exists in database too till the time I first read it .My first question was has this something to do with Windows Recycle Bin! But the answer is no.

Recycle Bin in database is actually a data dictionary table, which contains information about the dropped objects. So if you have ever dropped a table by mistake and wished you could undo that, recycle bin is to your rescue. When you drop a table, the database does not immediately remove the space associated with the table but instead it renames the table and places it and any associated objects in a recycle bin.

We can enable or disable the recycle bin using the initialization parameter recyclebin.

 

SQL> show parameter bin;

NAME TYPE VALUE
------------------------------------ ----------- -------------------
recyclebin string on

We can set/reset it for a particular session/system by using: -

Alter system set recyclebin=on/off
Alter session set recyclebin=on/off


Using Recycle Bin: -


A user can view his objects in the recycle bin by: -

 

SQL> select * from recyclebin;
No rows selected

Currently, the recyclebin for the user is empty.


Now lets create a table: -

 

SQL> create table test (a number);

Table created.

SQL> select * from recyclebin;

no rows selected

Now lets drop the table, which we created just now: -

 

SQL> drop table test;

Table dropped.

Lets peep into the recycle bin now,

 

SQL> select object_name, original_name, operation from recyclebin;

OBJECT_NAME ORIGINAL_NAME OPERATION
------------------------------ -------------------------------- ---------
BIN$VLKNkYA8S/arE/fy6G6LCg==$0 TEST DROP


When a dropped table is moved to the recycle bin, the table and its associated objects are given system-generated names so as to avoid name conflicts that may arise if multiple tables have the same name. Like if User A drops a table, re-creates it with the same name, then drops it again, there will be naming conflicts in the recyclebin or if two users have tables with the same name, and both users drop their tables.
The renaming convention, which the recyclebin follows, is: -
BIN$unique_id$version
Where:
Unique_id is a 26-character globally unique identifier for this object, which makes the recycle bin name unique across all databases
Version is a version number assigned by the database


We can query the object in the recycle bin in the same way we query other similar objects.

 

SQL> select * from BIN$VLKNkYA8S/arE/fy6G6LCg==$0;
No rows selected.

Removing from RecycleBin: -

This actually deals with two cases: -
1. We want to remove what’s their in recyclebin
2. We don’t want some particular tables to go to recycle bin, instead directly deleted

In the first case, we can use the PURGE command to remove the entries from the recyclebin. If we want to remove a particular table and all its associated entries, we can use: -

 

SQL> purge table test;

Table purged.

SQL> show recyclebin;

Here in purge table, we can specify the original name of the table or system generated names; the effect remains same for both the commands.

If we want to delete all the entries belonging to particular tablespace; we can use: -

 

SQL> purge tablespace <>;

And if we want to empty the complete recyclebin,

 	

SQL> purge recyclebin;

You cannot roll back a PURGE statement, nor can you recover an object after it is purged


In other case, while dropping the table; we can use the purge clause so that it is directly deleted and space is immediately free.


 

SQL> show recyclebin;

SQL> drop table test purge;
Table dropped.

SQL> show recyclebin;


Restoring from Recyclebin: -

To reinstate the table, all we have to do is use the “Flashback Table” command.

 

SQL>flashback table test to before drop rename to test;
Flashback complete.

SQL> select * from test;
A
----------
1
2

SQL> show recyclebin;

We can see the table test is back into the original state where it was before drop. But if the table has the indexes built on it, what happens to them? Lets see…

 

SQL> create table test(a number primary key);
Table created.
SQL> insert into test values(1);
1 row created.
SQL> insert into test values(2);
1 row created.
SQL> drop table test;
Table dropped.

SQL> select object_name,original_name,type from recyclebin;

OBJECT_NAME ORIGINAL_NAME
------------------------------ --------------------------------
TYPE
-------------------------
BIN$pjJQ48mbQl297TtOUMII6w==$0 SYS_C0016363
INDEX

BIN$a8rd/wnOQZexb+NOndiqjw==$0 TEST
TABLE

SQL> flashback table test to before drop rename to test;
Flashback complete.

SQL> select object_name,object_type from user_objects;

OBJECT_NAME OBJECT_TYPE
------------------------------ -------------------
PK_EMP INDEX
DEPT TABLE
PK_DEPT INDEX
EMP TABLE
BONUS TABLE
SALGRADE TABLE
TEST TABLE
BIN$pjJQ48mbQl297TtOUMII6w==$0 INDEX

8 rows selected.

The index still has the system-generated name assigned to it. If you want to get the original name back, you need to do it manually using

 

SQL> ALTER INDEX "BIN$pjJQ48mbQl297TtOUMII6w==$0" RENAME TO test_pk;

Index altered.

SQL> select object_name,object_type from user_objects;

OBJECT_NAME OBJECT_TYPE
------------------------------ -------------------
PK_EMP INDEX
DEPT TABLE
PK_DEPT INDEX
EMP TABLE
BONUS TABLE
SALGRADE TABLE
TEST TABLE
TEST_PK INDEX

8 rows selected.

Recyclebin also supports multiple versions of the same table so that we can get back to any older version: -


 

SQL> CREATE TABLE TEST (a NUMBER);
Table created.
SQL> INSERT INTO TEST VALUES (1);
1 row created.
SQL> COMMIT;
Commit complete.
SQL> DROP TABLE TEST;
Table dropped.

SQL> CREATE TABLE TEST (a NUMBER);
Table created.
SQL> INSERT INTO TEST VALUES (2);
1 row created.
SQL> COMMIT;
Commit complete.
SQL> DROP TABLE TEST;
Table dropped.

SQL> CREATE TABLE TEST (a NUMBER);
Table created.
SQL> INSERT INTO TEST VALUES (3);
1 row created.
SQL> COMMIT;
Commit complete.
SQL> DROP TABLE TEST;
Table dropped.

SQL> show recyclebin;

ORIGINAL NAME RECYCLEBIN NAME OBJECT TYPE DROP TIME
---------------- ------------------------------ ------------ -------------------

TEST BIN$JLFMRW9VTRCtxREKNeyDlg==$0 TABLE 2010-04-02:15:07:16

TEST BIN$nydz2eBWTM+UJKbCyfKGzw==$0 TABLE 2010-04-02:15:07:16

TEST BIN$sIjIxu4HRVu4gTp/KTKCkg==$0 TABLE 2010-04-02:15:07:16

Now we have all the three versions of test and we can restore to any table using our flashback command and using the recyclebin name.

 

SQL> Flashback table "BIN$sIjIxu4HRVu4gTp/KTKCkg==$0" to before drop rename to test3;

Flashback complete.

SQL> select * from test3;

COL1
----------
2



Wednesday, March 31, 2010

UNDO - My Understanding

Introduction: -

UNDO in Oracle database is used mainly to ensure that ACID (Atomicity, Consistency, Isolation, Durability) properties of a transaction are maintained.
UNDO is implemented using UNDO segments. It can be manually managed (using rollback segments) or system managed (using UNDO tablespace). Before Oracle 9i, it was manually managed but now we have a parameter (UNDO_MANAGEMENT) to configure if we want manual/auto.

SQL> show parameter undo_management

NAME TYPE VALUE
------------------------------------ ----------- -------------------------
undo_management string AUTO



UNDO Segments: -

As we know tablespace are made up of segments logically, similarly UNDO tablespace is made up of UNDO segments. We can see the list of UNDO segments with the help of table called dba_rollback_segs.

SQL> select segment_name, file_id, block_id from dba_rollback_segs where

tablespace_name ='UNDOTBS1';

SEGMENT_NAME FILE_ID BLOCK_ID
------------------------------ ---------- ----------
_SYSSMU1_1192467665$ 3 9
_SYSSMU2_1192467665$ 3 25
_SYSSMU3_1192467665$ 3 41
_SYSSMU4_1192467665$ 3 57
_SYSSMU5_1192467665$ 3 73
_SYSSMU6_1192467665$ 3 89
_SYSSMU7_1192467665$ 3 105
_SYSSMU8_1192467665$ 3 121
_SYSSMU9_1192467665$ 3 137
_SYSSMU10_1192467665$ 3 153

10 rows selected.

‘_SYSSMU’ is the prefix used for all the UNDO segments in case of auto UNDO management.


Each UNDO segment is made up of two distinct components: -
1. UNDO Header
2. UNDO entry

UNDO Header: -

The first block of UNDO segment is reserved for UNDO header and whenever a segment is created, only header is created and remaining blocks are just allocated to the segment with no structure defined. UNDO segment header mainly contains information about the UNDO extents and UNDO slots with the help of retention table, transaction table and extent control header.
We can dump UNDO segment header with: -

SQL> alter system dump undo header '_SYSSMU5_1192467665$';

Where '_SYSSMU5_1192467665$’ is the name of the segment to be dumped.
This dumps the contents of the segment header in the current trace file being used. The location of the trace file will be “ORACLE_BASE/diag/rdbms/<>/<>/trace/*.trc “.

Sample Trace File Contents: -


Undo Segment: _SYSSMU5_1192467665$ (5)
********************************************************************************
Extent Control Header
-----------------------------------------------------------------
Extent Header:: spare1: 0 spare2: 0 #extents: 231 #blocks: 34535
last map 0x00000000 #maps: 0 offset: 4080
Highwater:: 0x00c0b97d ext#: 227 blk#: 756 ext size: 1024
#blocks in seg. hdr's freelists: 0
#blocks below: 0
mapblk 0x00000000 offset: 227
Unlocked
Map Header:: next 0x00000000 #extents: 231 obj#: 0 flag: 0x40000000

Extent Map
-----------------------------------------------------------------
0x00c0004a length: 7
0x00c00051 length: 8
....
0x00c00989 length: 128
0x00c00011 length: 8
0x00c00021 length: 8

Retention Table
-----------------------------------------------------------
Extent Number:0 Commit Time: 1269847078
Extent Number:4 Commit Time: 1269847080
....
Extent Number:229 Commit Time: 1269847077
Extent Number:230 Commit Time: 1269847078

TRN CTL:: seq: 0x07ba chd: 0x0008 ctl: 0x0006 inc: 0x00000000 nfb: 0x0001
mgc: 0xb000 xts: 0x0068 flg: 0x0001 opt: 2147483646 (0x7ffffffe)
uba: 0x00c0b964.07ba.05 scn: 0x0000.0089a102
Version: 0x01
FREE BLOCK POOL::
uba: 0x00000000.07ba.04 ext: 0xe3 spc: 0x1df2
uba: 0x00000000.07ba.02 ext: 0xe3 spc: 0x1f0e
uba: 0x00c0b97c.07ba.07 ext: 0xe3 spc: 0x1940
uba: 0x00000000.057c.4d ext: 0x2 spc: 0x3c4
uba: 0x00000000.02ca.01 ext: 0x2 spc: 0x1f84
TRN TBL::

index state cflags wrap# uel scn dba parent-xid nub stmt_num cmt
------------------------------------------------------------------------------------------------
0x00 9 0x00 0x1a42 0x0019 0x0000.0089a332 0x00c0b97d 0x0000.000.00000000 0x00000001 0x00000000 1269853986
0x03 9 0x00 0x1a46 0x0017 0x0000.0089a19a 0x00c0b97b 0x0000.000.00000000 0x00000001 0x00000000 1269853441
......
0x20 9 0x00 0x1a43 0x0004 0x0000.0089a3ad 0x00c0b97d 0x0000.000.00000000 0x00000001 0x00000000 1269854042
0x21 9 0x00 0x1a4b 0x0006 0x0000.0089a433 0x00c0b964 0x0000.000.00000000 0x00000001 0x00000000 1269854282
EXT TRN CTL::
usn: 5
sp1:0x00000000 sp2:0x00000000 sp3:0x00000000 sp4:0x00000000
sp5:0x00000000 sp6:0x00000000 sp7:0x00000000 sp8:0x00000000
EXT TRN TBL::
index extflag extHash extSpare1 extSpare2
---------------------------------------------------
0x00 0x00000000 0x00000000 0x00000000 0x00000000
0x01 0x00000000 0x00000000 0x00000000 0x00000000
0x02 0x00000000 0x00000000 0x00000000 0x00000000
...
0x1f 0x00000000 0x00000000 0x00000000 0x00000000
0x20 0x00000000 0x00000000 0x00000000 0x00000000
0x21 0x00000000 0x00000000 0x00000000 0x00000000



From the dump, we can see the main components of the segment header: -
1. Extent Control Header
2. Extent Map
3. Retention Table
4. Free Block Pool
5. Transaction Table


Transaction Table: -

Undo is generated by a transaction and is valid only in context of that transaction. Transaction table is made up of fixed number of slots (entries). Every slot is assigned to a transaction. There are 3 main components in case of transaction table: - state, scn and dba. State can have a value of 10 for not committed transaction and 9 for committed transaction. DBA stands for data block address of last data block of UNDO entries for that transaction. An UNDO slot is made up of list of UNDO extents and UNDO extents comprise of set of UNDO block. Every UNDO block is assigned to only one transaction and has UNDO block header containing XID ,SQN etc information and UNDO records .


Two views play an important part here: - v$session and v$transaction.
v$session help in identifying the transaction it performed and gives the transaction number by TADDR column. If this column is NULL, then there is no transaction performed by the current session, otherwise we can find the more details in the v$transaction table about the transaction. If there isn't any transaction started yet,
Select * from v$transaction will yield " no rows returned " as the result.

SQL> select * from v$transaction;

No rows selected


Now issue an update...

SQL > update scott.emp set ename='parul' where empno=7934;
1 row updated.

With first DML issued, a XID is allocated to the transaction and thus a slot too containing the state of 10 (uncommitted transaction).

SQL> select ses_addr,addr,ubafil,ubablk,start_ubafil,start_ubablk from v$transaction;

SES_ADDR ADDR UBAFIL UBABLK START_UBAFIL START_UBABLK
-------- -------- ---------- ---------- ------------ ------------
99D69970 96E3CFA0 3 783 3 783


UBA here stands for Undo Block Address; Fil stands for File and Block stands for Block...
There are two things represented here.... UBAFIL and START_UBAFIL ... These are like head and tail of the transaction's UNDO chain.

Start_ubafil corresponds to the start of the undo chain, also called as the tail of the chain (since UNDO is used in the reverse order later).
And UBAFIL corresponds to the current UBA block in the chain, also called as the head of the chain. Hence, for every transaction; there is UNDO chain associated with multiple UNDO blocks, each identified by UBA (Undo Block Address). These blocks may not be physically adjacent to each other.

After we issue multiple updates , its still going on the same block but everytime for an update , a record is alocated :-
SQL> update scott.emp set job='analyst' where empno=7934;

1 row updated.

SQL> select ses_addr,addr,ubafil,ubablk,start_ubafil,start_ubablk from v$transaction;

SES_ADDR ADDR UBAFIL UBABLK START_UBAFIL START_UBABLK
-------- -------- ---------- ---------- ------------ ------------
99D69970 96E3CFA0 3 783 3 783

SQL>select used_ublk,used_urec, ubarec, start_ubarec from v$transaction;

USED_UBLK USED_UREC UBAREC START_UBAREC
------------ ------------ ------------
1 13 56 44


SQL> update scott.emp set ename='parul' where empno=7934;

1 row updated.

SQL> select used_ublk,used_urec, ubarec, start_ubarec from v$transaction;

USED_UBLK USED_UREC UBAREC START_UBAREC
------------ ------------ ------------
1 14 57 44

With every update, record count increases … and once, all the records are allocated; it assigns the records from the next block.



UNDO Entry

It contains transaction level information and contents of column before change occurred. UNDO entries are chained together to form single transaction UNDO action .
Every transaction is allocated a tranaction ID (XID) at the time of first DML statement which depends on three importants componenets :-
1. XIDUSN => Segment Number
2. XIDSLOT => Slot number from the transaction table
3. XIDSQN => Sequence Number

Dumping UNDO Block: -


Now suppose if we want to dump the UNDO block of the current transaction; we will get the block information from the v$transaction view: -

SQL> select ubafil,ubablk,ubarec from v$transaction;

UBAFIL UBABLK UBAREC
---------- ----------
3 47460 5

It tells us that the current transaction is using block with UBA 47460. We can find out from dba_extents, the file and block information for a particular extent.

SQL>select segment_name from dba_extents where file_id = 3
and 47460 between block_id and block_id + blocks –1;

SEGMENT_NAME
______________

_SYSSMU5_1192467665$

We found out the name of the segment, which contains the current block, and now we can dump the block from the file using

SQL> alter system dump datafile ‘_SYSSMU5_1192467665$’ block ‘47460’;

And this dumps the block into the trace file.

Sample Block Contents: -


*** 2010-03-29 17:54:12.187
Start dump data blocks tsn: 2 file#:3 minblk 47460 maxblk 47460
Block dump from cache:
Dump of buffer cache at level 4 for tsn=2, rdba=12630372
BH (0x187E434C) file#: 3 rdba: 0x00c0b964 (3/47460) class: 26 ba: 0x18408000
set: 3 bsz: 8192 bsi: 0 sflg: 0 pwc: 0 lid: 0x00000000,0x00000000
dbwrid: 0 obj: -1 objn: 0 tsn: 2 afn: 3
hash: [0x28197220,0x28197220] lru: [0x183F9E9C,0x18FEFDBC]
ckptq: [NULL] fileq: [NULL] objq: [0x1E3E877C,0x187F3CAC]
st: XCURRENT md: NULL tch: 7
flags: block_written_once redo_since_read gotten_in_current_mode
LRBA: [0x0.0.0] LSCN: [0x0.0] HSCN: [0xffff.ffffffff] HSUB: [1]
cr pin refcnt: 0 sh pin refcnt: 0
buffer tsn: 2 rdba: 0x00c0b964 (3/47460)
scn: 0x0000.0089a490 seq: 0x01 flg: 0x04 tail: 0xa4900201
frmt: 0x02 chkval: 0xcdd6 type: 0x02=KTU UNDO BLOCK
Hex dump of block: st=0, typ_found=1
Dump of memory from 0x18408000 to 0x1840A000
18408000 0000A202 00C0B964 0089A490 04010000 [....d...........]
18408010 0000CDD6 000E0005 00001A49 050507BA [........I.......]
....
18409FD0 0089A0FC 00060007 00001A23 00C08AB1 [........#.......]
18409FE0 00270675 00008000 0089831C 0000000D [u.'.............]
18409FF0 00814976 00801003 01010001 A4900201 [vI..............]

********************************************************************************
UNDO BLK:
xid: 0x0005.00e.00001a49 seq: 0x7ba cnt: 0x5 irb: 0x5 icl: 0x0 flg: 0x0000

Rec Offset Rec Offset Rec Offset Rec Offset Rec Offset
---------------------------------------------------------------------------
0x01 0x1f74 0x02 0x1f24 0x03 0x1e98 0x04 0x1e0c 0x05 0x1d84

*-----------------------------
* Rec #0x1 slt: 0x20 objn: 5965(0x0000174d) objd: 5965 tblspc: 1(0x00000001)
* Layer: 10 (Index) opc: 21 rci 0x00
Undo type: Regular undo Last buffer split: No
Temp Object: No
Tablespace Undo: No
rdba: 0x00c0b962
*-----------------------------
index general undo (branch) operations
KTB Redo
op: 0x05 ver: 0x01
compat bit: 4 (post-11) padding: 0
op: R itc: 2
Itl Xid Uba Flag Lck Scn/Fsc
0x01 0x0005.005.00001a42 0x00c0b963.07ba.01 C--- 0 scn 0x0000.0089a0fc
0x02 0x0007.006.00001a23 0x00c08ab1.0675.27 C--- 0 scn 0x0000.0089831c
Dump kdige : block dba :0x00814976, seghdr dba: 0x00801003
make leaf block empty
(2): 01 00

*-----------------------------
*-----------------------------
* Rec #0x5 slt: 0x0e objn: 69539(0x00010fa3) objd: 69539 tblspc: 4(0x00000004)
* Layer: 11 (Row) opc: 1 rci 0x00
Undo type: Regular undo Begin trans Last buffer split: No
Temp Object: No
Tablespace Undo: No
rdba: 0x00000000Ext idx: 0
flg2: 0
*-----------------------------
uba: 0x00c0b964.07ba.04 ctl max scn: 0x0000.0089a101 prv tx scn: 0x0000.0089a102
txn start scn: scn: 0x0000.00000000 logon user: 0
prev brb: 12630387 prev bcl: 0
KDO undo record:
KTB Redo
op: 0x03 ver: 0x01
compat bit: 4 (post-11) padding: 0
op: Z
KDO Op code: URP row dependencies Disabled
xtype: XA flags: 0x00000000 bdba: 0x0100001e hdba: 0x0100001b
itli: 2 ispac: 0 maxfr: 4858
tabn: 0 slot: 13(0xd) flag: 0x2c lock: 0 ckix: 0
ncol: 8 nnew: 1 size: 1
col 1: [ 6] 4d 49 4c 4c 45 52

Block dump from disk:
buffer tsn: 2 rdba: 0x00c0b964 (3/47460)
scn: 0x0000.0089a490 seq: 0x01 flg: 0x04 tail: 0xa4900201
…..

As we can see, in case of record 0x05; it contains the original value of the column name.
(col 1 : ……. )


We can analyze more further the block to see how it changes for multiple row updates or for delete. But this much is enough for basic understanding I guess.

References :-

1. www.juliandyke.com
2. http://www.scribd.com/doc/2713817/Oracle-AUTOMATIC-UNDO-INTERNALS