Creates an interface to a native or external procedure.
Quick Links:
CREATE[ OR REPLACE ] PROCEDURE [ owner.]procedure-name ( [ parameter, …] )
[ SQL SECURITY { INVOKER | DEFINER } ] [ RESULT ( result-column, …) | NO RESULT SET ] [ DYNAMIC RESULT SETS integer-expression ] [ EXTERNAL NAME ‘native-call’ | EXTERNAL NAME 'c-call' LANGUAGE { C_ESQL32 | C_ESQL64 | C_ODBC32 | C_ODBC64 } | EXTERNAL NAME 'perl-call' LANGUAGE PERL | EXTERNAL NAME 'php-call' LANGUAGE PHP | EXTERNAL NAME 'java-call' LANGUAGE JAVA } parameter - (back to Syntax) parameter_mode parameter-name data-type [ DEFAULT expression ] | SQLCODE | SQLSTATE parameter_mode - (back to parameter) IN | OUT | INOUT result-column - (back to Syntax) column-name data-type native-call - (back to Syntax) [operating-system:]function-name@library c-call - (back to Syntax) [operating-system:]function-name@library; ... perl-call - (back to Syntax) <file=perl-file> $sa_perl_return = perl-subroutine( $sa_perl_arg0[, ... ] ) php-call - (back to Syntax) <file=php-file> print php-func( $argv[1][, ... ] ) java-call - (back to Syntax) [package-name.]class-name.method-name method-signature operating-system - (back to native-call) or (back to c-call) Unix method-signature - (back to java-call) ( [ field-descriptor, ... ] ) return-descriptor field-descriptor and return-descriptor - (back to method-signature) { Z | B | S | I | J | F | D | C | V | [descriptor | Lclass-name; }
Parameters can be prefixed by one of the keywords IN, OUT or INOUT. If no keyword is specified, parameters are INOUT by default. The keywords have the following meanings:
Embedded SQL (LANGUAGE C_ESQL32, LANGUAGE C_ESQL64) or ODBC (LANGUAGE C_ODBC32, LANGUAGE C_ODBC64) external procedures can return 0 or 1 result sets.
Perl or PHP (LANGUAGE PERL, LANGUAGE PHP) external procedures cannot return result sets. Procedures that call native functions loaded by the database server cannot return result sets.
CLR or Java (LANGUAGE CLR, LANGUAGE JAVA) external procedures can return 0, 1, or more result sets.
The C_ESQL32, C_ESQL64, C_ODBC32, and C_ODBC64 external environments can also return result sets (like CLR and JAVA), but they are restricted to only one dynamic result set.
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.
Extra memory is used when you specify SQL SECURITY INVOKER, because annotation must be done for each user that calls the procedure. Also, name resolution is performed as the invoker as well. Therefore, qualify all object names (tables, procedures, and so on) with their appropriate owner. For example, suppose user1 creates this 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).
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. This 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 preceding EXTERNAL NAME clause, using platform-specific defaults:
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 executes as part of the server. In this case, if the function causes a fault, then the database server terminates. 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 continues to run.
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;
A Perl stored procedure or function behaves the same as an 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).
Sample procedure definition:
CREATE PROCEDURE PerlWriteToConsole( IN str LONG VARCHAR) NO RESULT SET EXTERNAL NAME '<file=PerlConsoleExample> WriteToServerConsole( $sa_perl_arg0 )' LANGUAGE PERL;
A PHP stored procedure or function behaves the same as an 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).
Sample procedure definition:
CREATE PROCEDURE PHPPopulateTable() NO RESULT SET EXTERNAL NAME '<file=ServerSidePHPExample> ServerSidePHPSub()' LANGUAGE PHP;
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 an 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).
Sample procedure definition:
CREATE PROCEDURE HelloDemo( IN name LONG VARCHAR ) NO RESULT SET EXTERNAL NAME 'Hello.main([Ljava/lang/String;)V' LANGUAGE JAVA;
The descriptors for arguments and return values from Java methods have the following meanings:
Field Type | Java Data Type |
---|---|
B | byte |
C | char |
D | double |
F | float |
I | int |
J | long |
L class-name; | an instance of the class-name class. The class name must be fully qualified, and any dot in the name must be replaced by a backslash. For example, java/lang/String |
S | short |
V | void |
Z | boolean |
[ | use one for each dimension of an array |
For example:
double some_method( boolean a, int b, java.math.BigDecimal c, byte [][] d, java.sql.ResultSet[] d ) { }
has the signature:
'(ZILjava/math/BigDecimal;[[B[Ljava/sql/ResultSet;)D'
The body of a procedure consists of a compound statement. For information on compound statements, see BEGIN … END Statement.
If a stored procedure returns a result set, it cannot also set output parameters or return a return value.
You cannot create TEMPORARY external call procedures.
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.
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.