Quick Search:
 
 Oracle PL/SQL: Oracle Exception Handling Jump to:  
Category: >> Oracle PL/SQL >> Oracle Exception Handling  

<< lastnext >>

Snippet Name: Oracle Exception Handling

Description: In PL/SQL, a warning or error condition is called an exception. Exceptions can be internally defined (by the run-time system) or user defined. Examples of internally defined exceptions include division by zero and out of memory. Some common internal exceptions have predefined names, such as ZERO_DIVIDE and STORAGE_ERROR. The other internal exceptions can be given names.

You can define exceptions of your own in the declarative part of any PL/SQL block, subprogram, or package. For example, you might define an exception named insufficient_funds to flag overdrawn bank accounts. Unlike internal exceptions, user-defined exceptions must be given names.

When an error occurs, an exception is raised. That is, normal execution stops and control transfers to the exception-handling part of your PL/SQL block or subprogram. Internal exceptions are raised implicitly (automatically) by the run-time system. User-defined exceptions must be raised explicitly by RAISE statements, which can also raise predefined exceptions.

To handle raised exceptions, you write separate routines called exception handlers. After an exception handler runs, the current block stops executing and the enclosing block resumes with the next statement. If there is no enclosing block, control returns to the host environment.

In the example given, we calculate and store a price-to-earnings ratio for a company with ticker symbol XYZ. If the company has zero earnings, the predefined exception ZERO_DIVIDE is raised. This stops normal execution of the block and transfers control to the exception handlers. The optional OTHERS handler catches all exceptions that the block does not name specifically.

An internal exception is raised implicitly whenever your PL/SQL program violates an Oracle rule or exceeds a system-dependent limit. Every Oracle error has a number, but exceptions must be handled by name. PL/SQL predefines some common Oracle errors as exceptions. For example, PL/SQL raises the predefined exception NO_DATA_FOUND if a SELECT INTO statement returns no rows.

To handle other Oracle errors, you can use the OTHERS handler. The functions SQLCODE and SQLERRM are especially useful in the OTHERS handler because they return the Oracle error code and message text. Alternatively, you can use the pragma EXCEPTION_INIT to associate exception names with Oracle error codes.

PL/SQL declares predefined exceptions globally in package STANDARD, which defines the PL/SQL environment. So, you need not declare them yourself. You can write handlers for predefined exceptions using the names in the list on the right.

Also see:
» Oracle Exception Handling
» SQL Code and SQL Error Messages
» PLSQL Errors

Comment: (none)

Language: PL/SQL
Highlight Mode: PLSQL
Last Modified: March 09th, 2009

DECLARE
   pe_ratio NUMBER(3,1);
BEGIN
   SELECT price / earnings INTO pe_ratio FROM stocks
      WHERE symbol = 'XYZ';  -- might cause division-by-zero error
   INSERT INTO stats (symbol, ratio) VALUES ('XYZ', pe_ratio);
   COMMIT;
EXCEPTION  -- exception handlers begin
   WHEN ZERO_DIVIDE THEN  -- handles 'division by zero' error
      INSERT INTO stats (symbol, ratio) VALUES ('XYZ', NULL);
      COMMIT;
   ...
   WHEN OTHERS THEN  -- handles all other errors
      ROLLBACK;
END;  -- exception handlers and block end here
 
The LAST example illustrates EXCEPTION handling, NOT the effective USE OF INSERT statements. FOR example, a better way TO DO the INSERT follows:
 
INSERT INTO stats (symbol, ratio)
   SELECT symbol, DECODE(earnings, 0, NULL, price / earnings)
   FROM stocks WHERE symbol = 'XYZ';
 
-- In the example above, a subquery supplies values to the 
-- INSERT statement. If earnings are zero, the function DECODE 
-- returns a null. Otherwise, DECODE returns the price-to-earnings 
-- ratio.
 
 
/*
Predefined PL/SQL Exceptions:
 
Error (Oracle Error / SQLCODE Value)
 
ACCESS_INTO_NULL (ORA-06530 / -6530)
Your program attempts to assign values to the attributes 
of an uninitialized (atomically null) object.
 
CASE_NOT_FOUND (ORA-06592 / -6592)
None of the choices in the WHEN clauses of a CASE statement 
is selected, and there is no ELSE clause.
 
COLLECTION_IS_NULL (ORA-06531 / -6531)
Your program attempts to apply collection methods other than 
EXISTS to an uninitialized (atomically null) nested table or varray, or the program attempts to assign values to the elements of an uninitialized nested table or varray.
 
CURSOR_ALREADY_OPEN (ORA-06511 / -6511)
Your program attempts to open an already open cursor. A 
cursor must be closed before it can be reopened. A cursor 
FOR loop automatically opens the cursor to which it refers. 
Your program cannot open that cursor inside the loop.
 
DUP_VAL_ON_INDEX (ORA-00001 / -1)
Your program attempts to store duplicate values in a database 
column that is constrained by a unique index.
 
INVALID_CURSOR (ORA-01001 / -1001)
Your program attempts an illegal cursor operation such as 
closing an unopened cursor.
 
INVALID_NUMBER (ORA-01722 / -1722)
In a SQL statement, the conversion of a character string into a 
number fails because the string does not represent a valid number. 
(In procedural statements, VALUE_ERROR is raised.) This exception 
is also raised when the LIMIT-clause expression in a bulk FETCH 
statement does not evaluate to a positive number.
 
LOGIN_DENIED (ORA-01017/ -1017)
Your program attempts to log on to Oracle with an invalid username 
and/or password.
 
NO_DATA_FOUND (ORA-01403 / +100)
A SELECT INTO statement returns no rows, or your program references 
a deleted element in a nested table or an uninitialized element in 
an index-by table. SQL aggregate functions such as AVG and SUM 
always return a value or a null. So, a SELECT INTO statement that 
calls an aggregate function never raises NO_DATA_FOUND. The FETCH 
statement is expected to return no rows eventually, so when that 
happens, no exception is raised.
 
NOT_LOGGED_ON (ORA-01012 / -1012)
Your program issues a database call without being connected to Oracle.
 
PROGRAM_ERROR (ORA-06501 / -6501)
PL/SQL has an internal problem.
 
ROWTYPE_MISMATCH  (ORA-06504 / -6504)
The host cursor variable and PL/SQL cursor variable involved in an 
assignment have incompatible return types. For example, when an open 
host cursor variable is passed to a stored subprogram, the return 
types of the actual and formal parameters must be compatible.
 
SELF_IS_NULL  (ORA-30625 / -30625)
Your program attempts to call a MEMBER method on a null instance. That 
is, the built-in parameter SELF (which is always the first parameter 
passed to a MEMBER method) is null.
 
STORAGE_ERROR  (ORA-06500 / -6500)
PL/SQL runs out of memory or memory has been corrupted.
 
SUBSCRIPT_BEYOND_COUNT  (ORA-06533 / -6533)
Your program references a nested table or varray element using an 
index number larger than the number of elements in the collection.
 
SUBSCRIPT_OUTSIDE_LIMIT  (ORA-06532 / -6532)
Your program references a nested table or varray element using an 
index number (-1 for example) that is outside the legal range.
 
SYS_INVALID_ROWID (ORA-01410 / -1410)
The conversion of a character string into a universal rowid fails 
because the character string does not represent a valid rowid.
 
TIMEOUT_ON_RESOURCE (ORA-00051 / -51)
A time-out occurs while Oracle is waiting for a resource.
 
TOO_MANY_ROWS (ORA-01422 / -1422)
A SELECT INTO statement returns more than one row.
 
VALUE_ERROR (ORA-06502 / -6502)
An arithmetic, conversion, truncation, or size-constraint error occurs. 
For example, when your program selects a column value into a character 
variable, if the value is longer than the declared length of the variable, 
PL/SQL aborts the assignment and raises VALUE_ERROR. In procedural 
statements, VALUE_ERROR is raised if the conversion of a character string 
into a number fails. (In SQL statements, INVALID_NUMBER is raised.)
 
ZERO_DIVIDE (ORA-01476 / -1476)
Your program attempts to divide a number by zero.
 
*/


 
   Home |    Search |    Code Library |    Sponsors |    Privacy |    Terms of Use |    Contact Us © 2003 - 2024 psoug.org