Stored procedures can have many input and output parameters.

    5.8.1. CREATE PROCEDURE

    Used for

    Creating a new stored procedure

    Available in

    DSQL, ESQL

    Syntax

    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 (‘;’).

    Statement 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 .

    Parameters

    Each parameter has a data type specified for it. 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 are presented as a parenthesized list following the name of the procedure. They are passed into the procedure as values, so anything that changes them inside the procedure has no effect on the parameters in the calling program. Input parameters may have default values. Those that do have values specified for them must be located 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.

    Use of Domains in Declarations

    A domain name can be specified as the type of a parameter. The parameter will inherit all domain attributes. If a default value is specified for the parameter, it overrides the default value specified in the domain definition.

    If the TYPE OF clause is added before the domain name, only the data type of the domain is used: any of the other attributes of the domain — NOT NULL constraint, CHECK constraints, default value — are neither checked nor used. However, if the domain is of a text type, its character set and collation sequence are always used.

    Use of Column Type in Declarations

    Input and output parameters can also be declared using the data type of columns in existing tables and views. The TYPE OF COLUMN clause is used for that, specifying relationname.columnname as its argument.

    When TYPE OF COLUMN is used, the parameter inherits only the data type and — for string types — the character set and collation sequence. The constraints and default value of the column are ignored.

    Bug warning for pre-Firebird 3 versions:

    For input parameters, the collation that comes with the column’s type is ignored in comparisons (e.g. equality tests). For local variables, the behaviour varies.

    The bug was fixed for Firebird 3.

    Variable and Cursor Declarations

    The optional declarations section, located last in the header section of the procedure definition, defines variables local to the procedure and its named cursors. Local variable declarations follow the same rules as parameters regarding specification of the data type. See details in the PSQL chapter for and DECLARE CURSOR.

    Procedure Body

    The header section is followed by the procedure body, consisting of one or more PSQL statements enclosed between the outer keywords BEGIN and END. Multiple BEGIN …​ END blocks of terminated statements may be embedded inside the procedure body.

    Any user connected to the database can create a new stored procedure. The user who creates a stored procedure becomes its owner.

    Examples

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

    1. CREATE PROCEDURE ADD_BREED (
    2. NAME D_BREEDNAME, /* Domain attributes are inherited */
    3. NAME_EN TYPE OF D_BREEDNAME, /* Only the domain type is inherited */
    4. SHORTNAME TYPE OF COLUMN BREED.SHORTNAME,
    5. /* The table column type is inherited */
    6. REMARK VARCHAR(120) CHARACTER SET WIN1251 COLLATE PXW_CYRL,
    7. CODE_ANIMAL INT NOT NULL DEFAULT 1
    8. )
    9. RETURNS (
    10. CODE_BREED INT
    11. )
    12. AS
    13. BEGIN
    14. INSERT INTO BREED (
    15. CODE_ANIMAL, NAME, NAME_EN, SHORTNAME, REMARK)
    16. VALUES (
    17. :CODE_ANIMAL, :NAME, :NAME_EN, :SHORTNAME, :REMARK)
    18. RETURNING CODE_BREED INTO CODE_BREED;
    19. END

    Creating a selectable stored procedure that generates data for mailing labels (from employee.fdb):

    1. CREATE PROCEDURE mail_label (cust_no INTEGER)
    2. RETURNS (line1 CHAR(40), line2 CHAR(40), line3 CHAR(40),
    3. line4 CHAR(40), line5 CHAR(40), line6 CHAR(40))
    4. AS
    5. DECLARE VARIABLE customer VARCHAR(25);
    6. DECLARE VARIABLE first_name VARCHAR(15);
    7. DECLARE VARIABLE last_name VARCHAR(20);
    8. DECLARE VARIABLE addr1 VARCHAR(30);
    9. DECLARE VARIABLE addr2 VARCHAR(30);
    10. DECLARE VARIABLE city VARCHAR(25);
    11. DECLARE VARIABLE state VARCHAR(15);
    12. DECLARE VARIABLE country VARCHAR(15);
    13. DECLARE VARIABLE postcode VARCHAR(12);
    14. BEGIN
    15. line1 = '';
    16. line2 = '';
    17. line3 = '';
    18. line4 = '';
    19. line5 = '';
    20. line6 = '';
    21. SELECT customer, contact_first, contact_last, address_line1,
    22. address_line2, city, state_province, country, postal_code
    23. FROM CUSTOMER
    24. WHERE cust_no = :cust_no
    25. INTO :customer, :first_name, :last_name, :addr1, :addr2,
    26. :city, :state, :country, :postcode;
    27. IF (customer IS NOT NULL) THEN
    28. line1 = customer;
    29. IF (first_name IS NOT NULL) THEN
    30. line2 = first_name || ' ' || last_name;
    31. ELSE
    32. line2 = last_name;
    33. IF (addr1 IS NOT NULL) THEN
    34. line3 = addr1;
    35. IF (addr2 IS NOT NULL) THEN
    36. line4 = addr2;
    37. IF (country = 'USA') THEN
    38. BEGIN
    39. IF (city IS NOT NULL) THEN
    40. line5 = city || ', ' || state || ' ' || postcode;
    41. ELSE
    42. line5 = state || ' ' || postcode;
    43. END
    44. ELSE
    45. BEGIN
    46. IF (city IS NOT NULL) THEN
    47. line5 = city || ', ' || state;
    48. ELSE
    49. line5 = state;
    50. line6 = country || ' ' || postcode;
    51. END
    52. SUSPEND; -- the statement that sends an output row to the buffer
    53. -- and makes the procedure "selectable"

    See also

    , ALTER PROCEDURE, , DROP PROCEDURE

    5.8.2. ALTER PROCEDURE

    Used for

    Modifying an existing stored procedure

    Available in

    DSQL, ESQL

    Syntax

    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.

    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.

    The procedure owner and have the authority to use ALTER PROCEDURE.

    ALTER PROCEDURE Example

    Altering the GET_EMP_PROJ stored procedure.

    1. ALTER PROCEDURE GET_EMP_PROJ (
    2. EMP_NO SMALLINT)
    3. RETURNS (
    4. PROJ_ID VARCHAR(20))
    5. AS
    6. FOR SELECT
    7. PROJ_ID
    8. FROM
    9. EMPLOYEE_PROJECT
    10. WHERE
    11. EMP_NO = :emp_no
    12. INTO :proj_id
    13. DO
    14. SUSPEND;
    15. END

    See also

    CREATE PROCEDURE, , RECREATE PROCEDURE,

    5.8.3. CREATE OR ALTER PROCEDURE

    Used for

    Creating a new stored procedure or altering an existing one

    Available in

    DSQL

    Syntax

    1. CREATE OR ALTER PROCEDURE procname
    2. [(<inparam> [, <inparam> ...])]
    3. [RETURNS (<outparam> [, <outparam> ...])]
    4. AS
    5. [<declarations>]
    6. BEGIN
    7. [<PSQL_statements>]
    8. END

    For the full syntax detail, see .

    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.

    Example

    Creating or altering the GET_EMP_PROJ procedure.

    See also

    CREATE PROCEDURE, , RECREATE PROCEDURE

    5.8.4. DROP PROCEDURE

    Used for

    Deleting a stored procedure

    Available in

    DSQL, ESQL

    Syntax

    1. DROP PROCEDURE procname

    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.

    The procedure owner and Administrators have the authority to use DROP PROCEDURE.

    Example

    Deleting the GET_EMP_PROJ stored procedure.

    1. DROP PROCEDURE GET_EMP_PROJ;

    See also

    , RECREATE PROCEDURE

    5.8.5. RECREATE PROCEDURE

    Used for

    Creating a new stored procedure or recreating an existing one

    Available in

    DSQL

    Syntax

    For the full syntax detail, see CREATE PROCEDURE.

    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.

    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.

    Example

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

    1. RECREATE PROCEDURE GET_EMP_PROJ (
    2. EMP_NO SMALLINT)
    3. RETURNS (
    4. PROJ_ID VARCHAR(20))
    5. AS
    6. BEGIN
    7. FOR SELECT
    8. PROJ_ID
    9. FROM
    10. EMPLOYEE_PROJECT
    11. WHERE
    12. EMP_NO = :emp_no
    13. INTO :proj_id
    14. DO
    15. SUSPEND;

    See also

    , ,