Creates an interface to a native or external procedure.
To create a SQL procedure, see CREATE PROCEDURE Statement . To create a table UDF or TPF, see CREATE PROCEDURE Statement (Table UDF).
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 ]
The body of a procedure consists of a compound statement. For information on compound statements, see BEGIN … END Statement.
CREATE PROCEDURE 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.
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.
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 mean:
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.
SQLSTATE and SQLCODE are special OUT parameters that output the SQLSTATE or SQLCODE value when the procedure ends. Whether or not a SQLSTATE and SQLCODE parameter is specified, the SQLSTATE and SQLCODE special values can always 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.
You cannot create TEMPORARY external call procedures.
For more information on returning result sets from procedures, see System Administration Guide: Volume 2 > Using Procedures and Batches.
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.
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 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 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).
A procedure that uses EXTERNAL NAME with a LANGUAGE JAVA clause is a wrapper around a Java method.
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. 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.
EXTERNAL NAME LANGUAGE ‘c-call’ LANGUAGE { C_ESQL32 | C_ESQL64 | C_ODBC32 | 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.
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;
EXTERNAL NAME ‘clr-call’ LANGUAGE CLR clr-call : dll-name::function-name ( param-type-1, ... )
operating-system: UNIX
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).
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;
EXTERNAL NAME ‘perl-call’ LANGUAGE CLR perl-call:
< file=perl-call > $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).
Sample procedure definition:
CREATE PROCEDURE PerlWriteToConsole( IN str LONG VARCHAR) NO RESULT SET EXTERNAL NAME '<file=PerlConsoleExample> WriteToServerConsole( $sa_perl_arg0 )' LANGUAGE PERL;
EXTERNAL NAME ‘perl-call’ LANGUAGE PHP <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).
Sample procedure definition:
CREATE PROCEDURE PHPPopulateTable() NO RESULT SET EXTERNAL NAME '<file=ServerSidePHPExample> ServerSidePHPSub()' LANGUAGE PHP;
EXTERNAL NAME java-call LANGUAGE JAVA ‘java-call‘ [ package-name. ] class-name.method-name ( method-signature
method-signature: ([field-descriptor, ... ] ) return-descriptor
A Java method signature is a compact character representation of the types of the parameters and the type of the return value.
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).
Sample procedure definition:
CREATE PROCEDURE HelloDemo( IN name LONG VARCHAR ) NO RESULT SET EXTERNAL NAME 'Hello.main([Ljava/lang/String;)V' LANGUAGE JAVA;
Field type |
Java data type |
---|---|
B |
byte |
C |
char |
D |
double |
F |
float |
I |
int |
J |
long |
Lclass-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 this signature:
'(ZILjava/math/BigDecimal;[[B[Ljava/sql/ResultSet;)D'
SQL—ISO/ANSI SQL compliant.
Sybase—The Transact-SQL CREATE PROCEDURE statement is different.
SQLJ—The syntax extensions for Java result sets are as specified in the proposed SQLJ1 standard.
Must have RESOURCE authority, unless creating a temporary procedure. For external procedures or to create a procedure for another user, must have DBA authority.