5.8PROCEDURE

A stored procedure is a software module that can be called from a client, another procedure, function, executable block or trigger. Stored procedures, stored functions, executable blocks and triggers are written in procedural SQL (PSQL). Most SQL statements are available in PSQL as well, sometimes with some limitations or extensions, notable limitations are DDL and transaction control statements.

Stored procedures can have many input and output parameters.

5.8.1CREATE PROCEDURE

Used forCreating a new stored procedure

Available inDSQL, ESQL

Syntax

   |CREATE PROCEDURE procname [ ( [ <in_params> ] ) ]
   |  [RETURNS (<out_params>)]
   |  <module-body>
   | 
   |<module-body> ::=
   |  !! See Syntax of Module Body !!
   | 
   |<in_params> ::= <inparam> [, <inparam> ...]
   | 
   |<inparam> ::= <param_decl> [{= | DEFAULT} <value>]
   | 
   |<out_params> ::= <outparam> [, <outparam> ...]
   | 
   |<outparam> ::= <param_decl>
   | 
   |<value> ::= {<literal> | NULL | <context_var>}
   | 
   |<param_decl> ::= paramname <domain_or_non_array_type> [NOT NULL]
   |  [COLLATE collation]
   | 
   |<type> ::=
   |    <datatype>
   |  | [TYPE OF] domain
   |  | TYPE OF COLUMN rel.col
   | 
   |<domain_or_non_array_type> ::=
   |  !! See Scalar Data Types Syntax !!

Table 5.23CREATE PROCEDURE Statement Parameters
ParameterDescription

procname

Stored procedure name consisting of up to 31 characters. Must be unique among all table, view and procedure names in the database

inparam

Input parameter description

outparam

Output parameter description

literal

A literal value that is assignment-compatible with the data type of the parameter

context_var

Any context variable whose type is compatible with the data type of the parameter

paramname

The name of an input or output parameter of the procedure. It may consist of up to 31 characters. The name of the parameter must be unique among input and output parameters of the procedure and its local variables

collation

Collation sequence

The CREATE PROCEDURE statement creates a new stored procedure. The name of the procedure must be unique among the names of all stored procedures, tables and views in the database.

CREATE PROCEDURE is a compound statement, consisting of a header and a body. The header specifies the name of the procedure and declares input parameters and the output parameters, if any, that are to be returned by the procedure.

The procedure body consists of declarations for any local variables and named cursors that will be used by the procedure, followed by one or more statements, or blocks of statements, all enclosed in an outer block that begins with the keyword BEGIN and ends with the keyword END. Declarations and embedded statements are terminated with semi-colons (;).

5.8.1.1Statement Terminators

Some SQL statement editors — specifically the isql utility that comes with Firebird and possibly some third-party editors — employ an internal convention that requires all statements to be terminated with a semi-colon. This creates a conflict with PSQL syntax when coding in these environments. If you are unacquainted with this problem and its solution, please study the details in the PSQL chapter in the section entitled Switching the Terminator in isql.

5.8.1.2Parameters

Each parameter has a data type. The NOT NULL constraint can also be specified for any parameter, to prevent NULL being passed or assigned to it.

A collation sequence can be specified for string-type parameters, using the COLLATE clause.

Input Parameters

Input parameters are presented as a parenthesized list following the name of the function. They are passed by value into the procedure, so any changes inside the procedure has no effect on the parameters in the caller. Input parameters may have default values. Parameters with default values specified must be added at the end of the list of parameters.

Output Parameters

The optional RETURNS clause is for specifying a parenthesised list of output parameters for the stored procedure.

5.8.1.3Variable, Cursor and Sub-Routine Declarations

The optional declarations section, located at the start of the body of the procedure definition, defines variables (including cursors) and sub-routines local to the procedure. Local variable declarations follow the same rules as parameters regarding specification of the data type. See details in the PSQL chapter for DECLARE VARIABLE, DECLARE CURSOR, DECLARE FUNCTION, and DECLARE PROCEDURE.

5.8.1.4External UDR Procedures

A stored procedure can also be located in an external module. In this case, instead of a procedure body, the CREATE PROCEDURE specifies the location of the procedure in the external module using the EXTERNAL clause. The optional NAME clause specifies the name of the external module, the name of the procedure inside the module, and — optionally — user-defined information. The required ENGINE clause specifies the name of the UDR engine that handles communication between Firebird and the external module. The optional AS clause accepts a string literal body, which can be used by the engine or module for various purposes.

5.8.1.5Who Can Create a Procedure

The CREATE PROCEDURE statement can be executed by:

The user executing the CREATE PROCEDURE statement becomes the owner of the table.

5.8.1.6Examples

  1. Creating a stored procedure that inserts a record into the BREED table and returns the code of the inserted record:

       |CREATE PROCEDURE ADD_BREED (
       |  NAME D_BREEDNAME, /* Domain attributes are inherited */
       |  NAME_EN TYPE OF D_BREEDNAME, /* Only the domain type is inherited */
       |  SHORTNAME TYPE OF COLUMN BREED.SHORTNAME,
       |    /* The table column type is inherited */
       |  REMARK VARCHAR(120) CHARACTER SET WIN1251 COLLATE PXW_CYRL,
       |  CODE_ANIMAL INT NOT NULL DEFAULT 1
       |)
       |RETURNS (
       |  CODE_BREED INT
       |)
       |AS
       |BEGIN
       |  INSERT INTO BREED (
       |    CODE_ANIMAL, NAME, NAME_EN, SHORTNAME, REMARK)
       |  VALUES (
       |    :CODE_ANIMAL, :NAME, :NAME_EN, :SHORTNAME, :REMARK)
       |  RETURNING CODE_BREED INTO CODE_BREED;
       |END
    
  2. Creating a selectable stored procedure that generates data for mailing labels (from employee.fdb):

       |CREATE PROCEDURE mail_label (cust_no INTEGER)
       |RETURNS (line1 CHAR(40), line2 CHAR(40), line3 CHAR(40),
       |         line4 CHAR(40), line5 CHAR(40), line6 CHAR(40))
       |AS
       |  DECLARE VARIABLE customer VARCHAR(25);
       |  DECLARE VARIABLE first_name VARCHAR(15);
       |  DECLARE VARIABLE last_name VARCHAR(20);
       |  DECLARE VARIABLE addr1 VARCHAR(30);
       |  DECLARE VARIABLE addr2 VARCHAR(30);
       |  DECLARE VARIABLE city VARCHAR(25);
       |  DECLARE VARIABLE state VARCHAR(15);
       |  DECLARE VARIABLE country VARCHAR(15);
       |  DECLARE VARIABLE postcode VARCHAR(12);
       |  DECLARE VARIABLE cnt INTEGER;
       |BEGIN
       |  line1 = '';
       |  line2 = '';
       |  line3 = '';
       |  line4 = '';
       |  line5 = '';
       |  line6 = '';
       | 
       |  SELECT customer, contact_first, contact_last, address_line1,
       |    address_line2, city, state_province, country, postal_code
       |  FROM CUSTOMER
       |  WHERE cust_no = :cust_no
       |  INTO :customer, :first_name, :last_name, :addr1, :addr2,
       |    :city, :state, :country, :postcode;
       | 
       |  IF (customer IS NOT NULL) THEN
       |    line1 = customer;
       |  IF (first_name IS NOT NULL) THEN
       |    line2 = first_name || ' ' || last_name;
       |  ELSE
       |    line2 = last_name;
       |  IF (addr1 IS NOT NULL) THEN
       |    line3 = addr1;
       |  IF (addr2 IS NOT NULL) THEN
       |    line4 = addr2;
       | 
       |  IF (country = 'USA') THEN
       |  BEGIN
       |    IF (city IS NOT NULL) THEN
       |  	  line5 = city || ', ' || state || '  ' || postcode;
       |  	ELSE
       |      line5 = state || '  ' || postcode;
       |  END
       |  ELSE
       |  BEGIN
       |    IF (city IS NOT NULL) THEN
       |  	  line5 = city || ', ' || state;
       |  	ELSE
       |      line5 = state;
       |    line6 = country || '    ' || postcode;
       |  END
       | 
       |  SUSPEND; -- the statement that sends an output row to the buffer
       |           -- and makes the procedure "selectable"
       |END
    

See alsoSection 5.8.3, “CREATE OR ALTER PROCEDURE, Section 5.8.2, “ALTER PROCEDURE, Section 5.8.5, “RECREATE PROCEDURE, Section 5.8.4, “DROP PROCEDURE

5.8.2ALTER PROCEDURE

Used forModifying an existing stored procedure

Available inDSQL, ESQL

Syntax

  |ALTER PROCEDURE procname [ ( [ <in_params> ] ) ]
  |  [RETURNS (<out_params>)]
  |  <module-body>
  | 
  |!! See syntax of CREATE PROCEDURE for further rules !!

The ALTER PROCEDURE statement allows the following changes to a stored procedure definition:

  • the set and characteristics of input and output parameters

  • local variables

  • code in the body of the stored procedure

After ALTER PROCEDURE executes, existing privileges remain intact and dependencies are not affected.

Caution

Take care about changing the number and type of input and output parameters in stored procedures. Existing application code and procedures and triggers that call it could become invalid because the new description of the parameters is incompatible with the old calling format. For information on how to troubleshoot such a situation, see the article The RDB$VALID_BLR Field in the Appendix.

5.8.2.1Who Can Alter a Procedure

The ALTER PROCEDURE statement can be executed by:

  • Administrators

  • The owner of the stored procedure

  • Users with the ALTER ANY PROCEDURE privilege

5.8.2.2ALTER PROCEDURE Example

Altering the GET_EMP_PROJ stored procedure.

   |ALTER PROCEDURE GET_EMP_PROJ (
   |  EMP_NO SMALLINT)
   |RETURNS (
   |  PROJ_ID VARCHAR(20))
   |AS
   |BEGIN
   |  FOR SELECT
   |      PROJ_ID
   |    FROM
   |      EMPLOYEE_PROJECT
   |    WHERE
   |      EMP_NO = :emp_no
   |    INTO :proj_id
   |  DO
   |    SUSPEND;
   |END

See alsoSection 5.8.1, “CREATE PROCEDURE, Section 5.8.3, “CREATE OR ALTER PROCEDURE, Section 5.8.5, “RECREATE PROCEDURE, Section 5.8.4, “DROP PROCEDURE

5.8.3CREATE OR ALTER PROCEDURE

Used forCreating a new stored procedure or altering an existing one

Available inDSQL

Syntax

  |CREATE OR ALTER PROCEDURE procname [ ( [ <in_params> ] ) ]
  |  [RETURNS (<out_params>)]
  |  <module-body>
  | 
  |!! See syntax of CREATE PROCEDURE for further rules !!

The CREATE OR ALTER PROCEDURE statement creates a new stored procedure or alters an existing one. If the stored procedure does not exist, it will be created by invoking a CREATE PROCEDURE statement transparently. If the procedure already exists, it will be altered and compiled without affecting its existing privileges and dependencies.

5.8.3.1CREATE OR ALTER PROCEDURE Example

Creating or altering the GET_EMP_PROJ procedure.

   |CREATE OR ALTER PROCEDURE GET_EMP_PROJ (
   |    EMP_NO SMALLINT)
   |RETURNS (
   |    PROJ_ID VARCHAR(20))
   |AS
   |BEGIN
   |  FOR SELECT
   |      PROJ_ID
   |    FROM
   |      EMPLOYEE_PROJECT
   |    WHERE
   |      EMP_NO = :emp_no
   |    INTO :proj_id
   |  DO
   |    SUSPEND;
   |END

See alsoSection 5.8.1, “CREATE PROCEDURE, Section 5.8.2, “ALTER PROCEDURE, Section 5.8.5, “RECREATE PROCEDURE

5.8.4DROP PROCEDURE

Used forDeleting a stored procedure

Available inDSQL, ESQL

Syntax

  |DROP PROCEDURE procname

Table 5.24DROP PROCEDURE Statement Parameter
ParameterDescription

procname

Name of an existing stored procedure

The DROP PROCEDURE statement deletes an existing stored procedure. If the stored procedure has any dependencies, the attempt to delete it will fail and the appropriate error will be raised.

5.8.4.1Who Can Drop a Procedure

The ALTER PROCEDURE statement can be executed by:

  • Administrators

  • The owner of the stored procedure

  • Users with the DROP ANY PROCEDURE privilege

5.8.4.2DROP PROCEDURE Example

Deleting the GET_EMP_PROJ stored procedure.

  |DROP PROCEDURE GET_EMP_PROJ;

See alsoSection 5.8.1, “CREATE PROCEDURE, Section 5.8.5, “RECREATE PROCEDURE

5.8.5RECREATE PROCEDURE

Used forCreating a new stored procedure or recreating an existing one

Available inDSQL

Syntax

  |RECREATE PROCEDURE procname [ ( [ <in_params> ] ) ]
  |  [RETURNS (<out_params>)]
  |  <module-body>
  | 
  |!! See syntax of CREATE PROCEDURE for further rules !!

The RECREATE PROCEDURE statement creates a new stored procedure or recreates an existing one. If there is a procedure with this name already, the engine will try to delete it and create a new one. Recreating an existing procedure will fail at the COMMIT request if the procedure has dependencies.

🛑
Warning

Be aware that dependency errors are not detected until the COMMIT phase of this operation.

After a procedure is successfully recreated, privileges to execute the stored procedure, and the privileges of the stored procedure itself are dropped.

5.8.5.1RECREATE PROCEDURE Example

Creating the new GET_EMP_PROJ stored procedure or recreating the existing GET_EMP_PROJ stored procedure.

   |RECREATE PROCEDURE GET_EMP_PROJ (
   |  EMP_NO SMALLINT)
   |RETURNS (
   |  PROJ_ID VARCHAR(20))
   |AS
   |BEGIN
   |  FOR SELECT
   |      PROJ_ID
   |    FROM
   |      EMPLOYEE_PROJECT
   |    WHERE
   |      EMP_NO = :emp_no
   |    INTO :proj_id
   |  DO
   |    SUSPEND;
   |END

See alsoSection 5.8.1, “CREATE PROCEDURE, Section 5.8.4, “DROP PROCEDURE, Section 5.8.3, “CREATE OR ALTER PROCEDURE