 |
|
Oracle Tips by Burleson |
Stored
Procedures
A stored or named procedure is a module of code,
stored in the database that can be called from another PL/SQL
program. It is passed one or more variables and executes an action
for the calling program. A procedure is created using the syntax
below.
create or
replace procedure <Name>
(<variable list>)
as (or is)
local
variable declaration
begin
code section
exceptions
end;
The OR REPLACE clause
allows the compiler to replace a procedure if a procedure of the same
name is already in the database schema. This is handy during
development so that you do not have to drop the procedure each time
before recreating it.
The procedure can be called any valid object
name. As with any database object, the procedure is created in the
user’s schema unless a schema name is provided. The example below
creates the procedure in the PUBS schema. Of course, the user that
creates the procedure must have rights granted to create objects in
another schema.
create or
replace procedure pubs.example_defaults
(n_1 in number := 5,
n_2 in number := 6,
n_3 in number := 7)
as
begin
dbms_output.put_line(n_1||n_2||n_3);
end;
/
The variable list is a comma delimited list of
variables in the format:
name mode type := default
All of these items have been discussed above in
the passing variables
section above. The heading ends
with the AS (or IS) clause. The heading takes the place of the
DECLARE clause
of the anonymous block. Local
variables are declared between the AS and BEGIN key words. For
clarity the developer may optionally want to append the procedure name
to the END clause at the end of the procedure. As with all PL/SQL blocks,
a procedure can contain an optional exceptions section (covered later
in this Chapter).
When a procedure is sent to the database, it is
compiled and stored in the database as an object. To execute the
procedure you must call it.
SQL> create
or replace procedure num_check
2 (n_numb IN number)
3 as
4 v_line varchar2(40);
5 begin
6 if n_numb < 10
7 then v_line:= 'Number OK';
8 else
9 v_line := 'Number Bad';
10 end if;
11 dbms_output.put_line(v_line);
12 end num_check;
13 /
Procedure
created.
The procedure heading is in lines 1, 2 and 3. One
variable is passed into the procedure in IN mode and is internally
named n_numb. A local variable called v_line is
declared on line 4. Lines 5 through 12 define the procedure body.
The procedure has been successfully compiled and loaded in the
database. It has not been executed. Querying user_objects
will show your procedures and their status.
SQL> set
pages 999
SQL> column object_name format a30
SQL> select
2 object_name,
3 object_type,
4 status
5 from user_objects;
OBJECT_NAME
OBJECT_TYPE STATUS
------------------------------ ------------------ -------
AUTHOR TABLE VALID
BOOK TABLE VALID
BOOK_AUTHOR TABLE VALID
EMP TABLE VALID
EXAMPLE_DEFAULTS PROCEDURE INVALID
JOB TABLE VALID
NUM_CHECK PROCEDURE VALID
PUBLISHER TABLE VALID
SALES TABLE VALID
STORE TABLE VALID
10 rows
selected.
If the procedure did not compile correctly, it
will still be loaded in the database but will be marked invalid as
shown in the example_defaults procedure above. This invalid
procedure was created earlier in the variable passing section.
SQL> create
or replace procedure example_defaults
2 (n_1 in number := 5,
3 n_2 in number := 6,
4 n_3 in number := 7)
5 as
6 begin
7 n_1 := n_2 + n_3;
8 end;
9 /
Warning:
Procedure created with compilation errors.
To see the
compilation errors from SQL*Plus enter ‘show errors’;
SQL> show
errors
Errors for
PROCEDURE EXAMPLE_DEFAULTS:
LINE/COL
ERROR
-------- ------------------------------------------------
7/3 PLS-00363: expression 'N_1' cannot be used as an assignment
target
To remove the
procedure from the database, simply drop it.
SQL> drop
procedure example_defaults;
Procedure
dropped.
Once the procedure is in the database it can be
called in a variety of ways using SQL*Plus, another
PL/SQL block or from an external application connect to the database
such as Java, Perl, etc.
The above book excerpt is from:
Easy Oracle PL/SQL Programming
Get Started
Fast with Working PL/SQL Code Examples
ISBN 0-9759135-7-3
John Garmany
http://www.rampant-books.com/book_2005_1_easy_plsql.htm
|