The CREATE DBPROC[EDURE] statement (create_dbproc_statement) defines a database procedure.
<create_dbproc_statement> ::= CREATE DBPROC[EDURE] <dbproc_name> [(<formal_parameter>,...)] [RETURNS CURSOR] AS <routine>
<formal_parameter> ::=
IN <argument> <data_type>
| OUT <argument> <data_type>
| INOUT <argument> <data_type>
<argument> ::= <identifier>
SQL Tutorial, Database Procedures
If no schema is specified in the database procedure name, the current schema is assumed implicitly.
The database procedure is assigned to the schema that has been determined implicitly or specified explicitly. The current user must have the CREATEIN privilege for this schema. The procedure name must be different from the names of the database procedures already existing in the schema.
The current user is the owner of a database procedure. He or she has the EXECUTE privilege to execute the database procedure.
When an application invokes the database procedure with the CALL statement, it exchanges data using parameters defined by means of formal parameters (formal_parameter). A formal parameter of the database procedure usually corresponds to a variable in the application.
The parameter mode (IN | OUT | INOUT) specifies the direction in which data is transferred when the procedure is called.
● IN: Defines an input parameter, i.e. the value of the variable transferred to the database procedure when the procedure is invoked.
● OUT: Defines an output parameter. This means the value of the formal parameter is transferred from the database procedure to the variable after the procedure has been terminated.
● INOUT: Defines an input/output parameter that combines the IN and OUT functions.
By specifying an argument (argument), you assign a name to a formal parameter of the database procedure. This parameter name can then be used as a variable in expressions and assignments in the database procedure.
BOOLEAN, CHAR[ACTER], DATE, FIXED, FLOAT, INT[EGER], NUMBER, REAL, SMALLINT, TIME, TIMESTAMP, and VARCHAR only can be used for the data type (data_type) of a formal parameter in a database procedure.
If RETURNS CURSOR is specified, a database procedure is defined that returns a results table when called.
The name of this table is defined using the system variable $CURSOR. A statement must therefore be contained in the database procedure that generates a results table with the result set name $CURSOR.
The value of $CURSOR is already assigned by most programming language embeddings, but can also be explicitly assigned in the database procedure.
CREATE DBPROC
hotels_of_town (IN zip CHAR(5))
RETURNS CURSOR AS
$CURSOR = 'HOTEL_CURSOR';
DECLARE :$CURSOR CURSOR FOR
SELECT * FROM hotel.hotel WHERE zip = :zip;
See also:
CREATE SYSTEM TRIGGER Statement