The CREATE DBPROC statement (create_dbproc_statement) defines a database procedure.
<create_dbproc_statement> ::= CREATE DBPROC <procedure_name> [(<formal_parameter>,..)] [RETURNS CURSOR] AS <routine>
<formal_parameter>
::=
IN <argument> <data_type>
| OUT <argument> <data_type>
| INOUT <argument> <data_type>
<argument> ::= <identifier>
procedure_name, data_type, identifier, routine
The database procedure determines the average price for single rooms in hotels that are located within the specified zip code range.
CREATE DBPROC avg_price (IN zip CHAR(5), OUT avg_price FIXED(6,2)) AS
VAR sum FIXED(10,2); price FIXED(6,2); hotels
INTEGER;
TRY
SET sum = 0; SET hotels = 0;
SELECT price FROM travel.room,travel.hotel WHERE zip = :zip
AND
room.hno = hotel.hno AND roomtype = 'SINGLE';
WHILE $rc = 0 DO BEGIN
FETCH INTO :price;
SET sum = sum + price;
SET hotels = hotels + 1;
END;
CATCH
IF $rc <> 100 THEN STOP ($rc, 'unexpected error');
IF hotels > 0 THEN SET avg_price = sum / hotels
ELSE STOP (100, 'no hotel found');
The current user is the owner of a database procedure. He or she has the EXECUTE privilege to execute the procedure.
When an application invokes the database procedure with the CALL statement, it exchanges data via parameters that are defined by means of the formal parameters. 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 the data is transferred when the procedure is invoked.
IN: defines an input parameter, i.e. the value of the variable is transferred to the database procedure when the procedure is invoked.
OUT: defines an output parameter, i.e. the value of the formal parameter is transferred from the database procedure to the variable after the procedure has terminated.
INOUT: defines an input/output parameter that combines the IN and OUT functions.
By specifying an 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.
Only BOOLEAN, CHAR[ACTER], DATE, FIXED, FLOAT, INT[EGER], NUMBER, REAL, SMALLINT, TIME, TIMESTAMP, and VARCHAR can be used as the data type of a formal parameter of 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. There must therefore be a statement 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 travel.hotel WHERE zip = :zip;