CREATE PROCEDURE (SQL procedures)
Use the CREATE PROCEDURE command to create
SQL procedures.
This command defines the structure and operation of the procedure, including the types of parameter passed into, and out of, the procedure, and the local variables, condition testing, row operations, and assignments that are performed in the procedure.
Syntax
CREATE [ OR REPLACE ] PROCEDURE procedure_name
([
[ IN | OUT | IN OUT ] parameter_name
{ parameter_type | ARRAY OF parameter_type }, ...
])
[ DECLARE variable_declaration;...[;] ]
BEGIN
procedure_body_statement;...[;]
ENDIf there is a possibility that a procedure already exists with the same name as the one you want to create, use the optional OR REPLACE keywords. If the procedure exists, it is replaced by the one you are creating. If the procedure does not exist, a new one is created.
The procedure_name must be unique within the ObjectServer and comply with the ObjectServer naming conventions.
Following the procedure_name, specify the parameters that can be passed into, or out of, the procedure, within parentheses ( ). You must include parentheses after the procedure_name even if the procedure has no parameters.
Each procedure parameter has a mode, which can be IN, OUT, or IN OUT. Depending on the mode that you choose for your parameters, you can use them in different ways:
- An IN parameter is a read-only variable. You can use an IN parameter in expressions to help calculate a value, but you cannot assign a value to the parameter. If you do not want to change a variable value within the procedure, use an IN parameter to pass the variable value into the procedure. This parameter is used by default if you do not specify the parameter mode.
- An OUT parameter is a write-only variable. You can use an OUT parameter to assign a value to the parameter, but you cannot read from it within the body of the procedure. Therefore, you cannot use this type of parameter in an expression. OUT parameters are useful for passing values that are computed within a procedure, out of the procedure.
- An IN OUT parameter is a read and write variable, with none of the constraints of an IN or OUT parameter. This parameter is useful for variables that you want to change within the procedure, and pass out of the procedure.
The parameter_name must be unique within the procedure and comply with the ObjectServer naming conventions.
The parameter_type defines the type of data that the parameter can pass into, or out of, the procedure. The data type can be any valid ObjectServer data type, except VARCHAR or INCR.
An ARRAY OF parameter_type is
an array of any valid parameter type.
In the optional DECLARE section of a procedure, you can define (declare) local variables for use within a procedure. A local variable is a placeholder for values used during the execution of the procedure. Use semicolons to separate local variable declarations. Variable names must be unique within the procedure and comply with the ObjectServer naming conventions. The variable_declaration can include either of the following variable types:
- Simple variables:
variable_name variable_type - Array variables:
variable_name variable_type [ ARRAY ] [ integer ]A variable_type is any valid ObjectServer data type, except VARCHAR or INCR.
Define the size of an array by specifying an integer value greater than 1 in square brackets.
Note: The square brackets in bold type around the integer value are required to specify the size of the array; they do not indicate syntax notation for an optional keyword or clause.
The body of a procedure is enclosed within the keywords BEGIN and END. You can use the SET statement, IF THEN ELSE statement, CASE WHEN statement, FOR EACH ROW loop, and FOR loop in the procedure body.
Example
In the following procedure declaration,
the formal parameter is the variable current_severity.
When you run the procedure, you pass an actual parameter.
CREATE PROCEDURE calculate_average_severity
( IN current_severity INTEGER )For example, in the
following procedure call, the actual parameter is the value 5,
which is assigned to the formal parameter current_severity.
EXECUTE PROCEDURE calculate_average_severity(5);Example
CREATE PROCEDURE add_or_concat
( IN counter INTEGER, IN one_char_string CHAR(1))Example
In the following example, an array of integers is passed into the procedure and used to calculate the average severity of a subset of alerts:
CREATE PROCEDURE calculate_average_severity
( IN severity_arr ARRAY OF INTEGER)An array of integers
is passed into the procedure when you run it. These integers are assigned
to an array named severity_arr.
Example
To create a Boolean variable used in the procedure to indicate when a severity exceeds a particular value:
DECLARE SeverityTooHigh BOOLEAN;
To create an array of 20 integer values used in the procedure to store node names:
DECLARE NodeNameArray INTEGER [20];