CREATE PROCEDURE statement (external procedures)

Use this statement to create an interface to a native or external procedure. To create a SQL procedure, see CREATE PROCEDURE statement.

Syntax
CREATE [ OR REPLACE ] PROCEDURE [ owner.]procedure-name 
     ( [ parameter, ... ] )
[ RESULT ( result-column, ... ) | NO RESULT SET ]
[ DYNAMIC RESULT SETS integer-expression ]
[ SQL SECURITY { INVOKER | DEFINER } ]
EXTERNAL NAME 'external-call' [ LANGUAGE environment-name  ] 
parameter :
  [ parameter-mode ] parameter-name data-type [ DEFAULT expression ]
| SQLCODE
| SQLSTATE
parameter-mode : IN 
| OUT 
| INOUT
result-column : column-name data-type
environment-name : 
  C_ESQL32
| C_ESQL64
| C_ODBC32
| C_ODBC64
| CLR
| JAVA
| PERL
| PHP
Parameters
  • CREATE PROCEDURE   You can create permanent stored procedures that call external or native procedures written in a variety of programming languages. You can use PROC as a synonym for PROCEDURE.

    Parameter names must conform to the rules for other database identifiers such as column names. They must be a valid SQL data type. For a list of valid data types, see SQL data types.

    Parameters can be prefixed with one of the keywords IN, OUT, or INOUT. If you do not specify one of these values, parameters are INOUT by default. The keywords have the following meanings:

    • IN   The parameter is an expression that provides a value to the procedure.

    • OUT   The parameter is a variable that could be given a value by the procedure.

    • INOUT   The parameter is a variable that provides a value to the procedure, and could be given a new value by the procedure.

    When procedures are executed using the CALL statement, not all parameters need to be specified. If a default value is provided in the CREATE PROCEDURE statement, missing parameters are assigned the default values. If an argument is not provided in the CALL statement, and no default is set, an error is given.

    SQLSTATE and SQLCODE are special OUT parameters that output the SQLSTATE or SQLCODE value when the procedure ends. The SQLSTATE and SQLCODE special values can be checked immediately after a procedure call to test the return status of the procedure.

    The SQLSTATE and SQLCODE special values are modified by the next SQL statement. Providing SQLSTATE or SQLCODE as procedure arguments allows the return code to be stored in a variable.

    Specifying OR REPLACE (CREATE OR REPLACE PROCEDURE) creates a new procedure, or replaces an existing procedure with the same name. This clause changes the definition of the procedure, but preserves existing permissions. An error is returned if you attempt to replace a procedure that is already in use.

    You cannot create TEMPORARY external call procedures.

  • RESULT clause   The RESULT clause declares the number and type of columns in the result set. The parenthesized list following the RESULT keyword defines the result column names and types. This information is returned by the embedded SQL DESCRIBE or by ODBC SQLDescribeCol when a CALL statement is being described.For a list of data types, see SQL data types.

    Procedures that call into Embedded SQL (LANGUAGE C_ESQL32, LANGUAGE C_ESQL64) or ODBC (LANGUAGE C_ODBC32, LANGUAGE C_ODBC64) external functions can return 0 or 1 result sets.

    Procedures that call into Perl or PHP (LANGUAGE PERL, LANGUAGE PHP) external functions cannot return result sets. Procedures that call native functions loaded by the database server cannot return result sets.

    Procedures that call into CLR or Java (LANGUAGE CLR, LANGUAGE JAVA) external functions can return 0, 1, or more result sets.

    Some procedures can produce more than one result set, with different numbers of columns, depending on how they are executed. For example, the following procedure returns two columns under some circumstances, and one in others.

    CREATE PROCEDURE names( IN formal char(1))
    BEGIN
       IF formal = 'n' THEN
          SELECT GivenName
          FROM Employees
       ELSE
          SELECT Surname, GivenName
          FROM Employees
       END IF
    END;

    Procedures with variable result sets must be written without a RESULT clause, or in Transact-SQL. Their use is subject to the following limitations:

    • Embedded SQL   You must DESCRIBE the procedure call after the cursor for the result set is opened, but before any rows are returned, to get the proper shape of result set. The CURSOR cursor-name clause on the DESCRIBE statement is required.

    • ODBC, OLE DB, ADO.NET   Variable result-set procedures can be used by applications using these interfaces. The proper description of the result sets is carried out by the driver or provider.

    • Open Client applications   Variable result-set procedures can be used by Open Client applications.

    If your procedure returns only one result set, you should use a RESULT clause. The presence of this clause prevents ODBC and Open Client applications from re-describing the result set after a cursor is open.

    To handle multiple result sets, ODBC must describe the currently executing cursor, not the procedure's defined result set. Therefore, ODBC does not always describe column names as defined in the RESULT clause of the procedure definition. To avoid this problem, use column aliases in the SELECT statement that generates the result set.

    For more information about returning result sets from procedures, see Returning results from procedures.

  • NO RESULT SET clause   Declares that no result set is returned by this procedure. This declaration can lead to a performance improvement.

  • DYNAMIC RESULT SETS clause   Use this clause with LANGUAGE CLR and LANGUAGE JAVA calls. If the DYNAMIC RESULT SETS clause is not provided, it is assumed that the method returns no result set.

    Note that procedures that call into Perl or PHP (LANGUAGE PERL, LANGUAGE PHP) external functions cannot return result sets. Procedures that call native functions loaded by the database server cannot return result sets.

  • SQL SECURITY clause   The SQL SECURITY clause defines whether the procedure is executed as the INVOKER (the user who is calling the procedure), or as the DEFINER (the user who owns the procedure). The default is DEFINER. For external calls, this clause establishes the ownership context for unqualified object references in the external environment.

    When SQL SECURITY INVOKER is specified, more memory is used because annotation must be done for each user that calls the procedure. Also, when SQL SECURITY INVOKER is specified, name resolution is done as the invoker as well. Therefore, care should be taken to qualify all object names (tables, procedures, and so on) with their appropriate owner. For example, suppose user1 creates the following procedure:

    CREATE PROCEDURE user1.myProcedure()
       RESULT( columnA INT )
       SQL SECURITY INVOKER
       BEGIN
         SELECT columnA FROM table1;
       END;

    If user2 attempts to run this procedure and a table user2.table1 does not exist, a table lookup error results. Additionally, if a user2.table1 does exist, that table is used instead of the intended user1.table1. To prevent this situation, qualify the table reference in the statement (user1.table1, instead of just table1).

  • EXTERNAL NAME 'native-call' clause  

    EXTERNAL NAME 'native-call'
    native-call :
    [operating-system:]function-name@library; ...
    
    operating-system : Unix
    

    A procedure using the EXTERNAL NAME clause with no LANGUAGE attribute defines an interface to a native function written in a programming language such as C. The native function is loaded by the database server into its address space.

    The library name can include the file extension, which is typically .dll on Windows and .so on Unix. In the absence of the extension, the software appends the platform-specific default file extension for libraries. The following is a formal example.

    CREATE PROCEDURE mystring( IN instr LONG VARCHAR )
    EXTERNAL NAME 'mystring@mylib.dll;Unix:mystring@mylib.so';
    

    A simpler way to write the above EXTERNAL NAME clause, using platform-specific defaults, is as follows:

    CREATE PROCEDURE mystring( IN instr LONG VARCHAR )
    EXTERNAL NAME 'mystring@mylib';
    

    When called, the library containing the function is loaded into the address space of the database server. The native function will execute as part of the server. In this case, if the function causes a fault, then the database server will be terminated. Because of this, loading and executing functions in an external environment using the LANGUAGE attribute is recommended. If a function causes a fault in an external environment, the database server will continue to run.

    For information about native library calls, see Calling external libraries from procedures.

  • EXTERNAL NAME 'c-call' LANGUAGE {C_ESQL32 | C_ESQL64 | C_ODBC32 | C_ODBC64 } clause  

    EXTERNAL NAME 'c-call' LANGUAGE C_ESQL32
    EXTERNAL NAME 'c-call' LANGUAGE C_ESQL64
    EXTERNAL NAME 'c-call' LANGUAGE C_ODBC32
    EXTERNAL NAME 'c-call' LANGUAGE C_ODBC64
    c-call :
    [operating-system:]function-name@library; ...
    
    operating-system : Unix
    

    To call a compiled native C function in an external environment instead of within the database server, the stored procedure or function is defined with the EXTERNAL NAME clause followed by the LANGUAGE attribute specifying one of C_ESQL32, C_ESQL64, C_ODBC32, or C_ODBC64.

    When the LANGUAGE attribute is specified, then the library containing the function is loaded by an external process and the external function will execute as part of that external process. In this case, if the function causes a fault, then the database server will continue to run.

    The following is a sample procedure definition.

    CREATE PROCEDURE ODBCinsert( 
      IN ProductName CHAR(30),
      IN ProductDescription CHAR(50)
    )
    NO RESULT SET
    EXTERNAL NAME 'ODBCexternalInsert@extodbc.dll'
    LANGUAGE C_ODBC32;

    For more information, see The ESQL and ODBC external environments.

  • EXTERNAL NAME clr-call LANGUAGE CLR clause  

    EXTERNAL NAME 'clr-call' LANGUAGE CLR
    clr-call :
    dll-name::function-name( param-type-1, ... )
    

    To call a .NET function in an external environment, the procedure interface is defined with an EXTERNAL NAME clause followed by the LANGUAGE CLR attribute.

    A CLR stored procedure or function behaves the same as a SQL stored procedure or function with the exception that the code for the procedure or function is written in a .NET language such as C# or Visual Basic, and the execution of the procedure or function takes place outside the database server (that is, within a separate .NET executable).

    The following is a sample procedure definition.

    CREATE PROCEDURE clr_interface( 
        IN p1 INT, 
        IN p2 UNSIGNED SMALLINT, 
        OUT p3 LONG VARCHAR) 
    NO RESULT SET
    EXTERNAL NAME 'CLRlib.dll::CLRproc.Run( int, ushort, out string )' 
    LANGUAGE CLR;

    For more information, see The CLR external environment.

  • EXTERNAL NAME perl-call LANGUAGE PERL clause  

    EXTERNAL NAME 'perl-call' LANGUAGE PERL
    perl-call :
    <file=perl-file> $sa_perl_return = perl-sub( $sa_perl_arg0, ... ) 
    

    To call a Perl function in an external environment, the procedure interface is defined with an EXTERNAL NAME clause followed by the LANGUAGE PERL attribute.

    A Perl stored procedure or function behaves the same as a SQL stored procedure or function with the exception that the code for the procedure or function is written in Perl and the execution of the procedure or function takes place outside the database server (that is, within a Perl executable instance).

    The following is a sample procedure definition.

    CREATE PROCEDURE PerlWriteToConsole( IN str LONG VARCHAR) 
    NO RESULT SET
    EXTERNAL NAME '<file=PerlConsoleExample> 
        WriteToServerConsole( $sa_perl_arg0 )'
    LANGUAGE PERL;

    For more information, see The PERL external environment.

  • EXTERNAL NAME php-call LANGUAGE PHP clause  

    EXTERNAL NAME 'php-call' LANGUAGE PHP
    php-call :
    <file=php-file> print php-func( $argv[1], ... ) 
    

    To call a PHP function in an external environment, the procedure interface is defined with an EXTERNAL NAME clause followed by the LANGUAGE PHP attribute.

    A PHP stored procedure or function behaves the same as a SQL stored procedure or function with the exception that the code for the procedure or function is written in PHP and the execution of the procedure or function takes place outside the database server (that is, within a PHP executable instance).

    The following is a sample procedure definition.

    CREATE PROCEDURE PHPPopulateTable() 
    NO RESULT SET
    EXTERNAL NAME '<file=ServerSidePHPExample> ServerSidePHPSub()'
    LANGUAGE PHP;

    For more information, see The PHP external environment.

  • EXTERNAL NAME java-call LANGUAGE JAVA clause  

    EXTERNAL NAME 'java-call' LANGUAGE JAVA
    java-call :
    [package-name.]class-name.method-name method-signature
    
    method-signature : 
    ( [ field-descriptor, ... ] ) return-descriptor
    
    field-descriptor and return-descriptor :
    Z 
    | B 
    | S 
    | I 
    | J 
    | F 
    | D 
    | C 
    | V 
    | [descriptor 
    | Lclass-name;
    

    To call a Java method in an external environment, the procedure interface is defined with an EXTERNAL NAME clause followed by the LANGUAGE JAVA attribute.

    A Java-interfacing stored procedure or function behaves the same as a SQL stored procedure or function with the exception that the code for the procedure or function is written in Java and the execution of the procedure or function takes place outside the database server (that is, within a Java Virtual Machine).

    The following is a sample procedure definition.

    CREATE PROCEDURE HelloDemo( IN name LONG VARCHAR ) 
    NO RESULT SET
    EXTERNAL NAME 'Hello.main([Ljava/lang/String;)V'
    LANGUAGE JAVA;

    For more information, see The Java external environment.

Remarks

The CREATE PROCEDURE statement creates a procedure in the database. Users with DBA authority can create procedures for other users by specifying an owner. A procedure is invoked with a CALL statement.

If a stored procedure returns a result set, it cannot also set output parameters or return a return value.

When referencing a temporary table from multiple procedures, a potential issue can arise if the temporary table definitions are inconsistent and statements referencing the table are cached. See Referencing temporary tables within procedures.

Permissions

Must have RESOURCE authority, unless creating a temporary procedure.

Must have DBA authority for external procedures or to create a procedure for another user.

Side effects

Automatic commit.

See also
Standards and compatibility
  • SQL/2003   Persistent Stored Module feature. The syntax extensions for Java result sets are as specified in the optional J621 feature.