CREATE PROCEDURE Statement (External Procedures)

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

Syntax

CREATEOR REPLACE ] PROCEDUREowner.]procedure-name ( [ parameter, …] ) 
[ RESULTresult-column, …) | NO RESULT SET ]  
[  DYNAMIC RESULT SETS integer-expression ]
 [ SQL SECURITY { INVOKER | DEFINER } ] 
[ EXTERNAL NAME external-call’ [ LANGUAGE environment-name ]

Parameters

Usage

The body of a procedure consists of a compound statement. For information on compound statements, see BEGIN … END Statement.

Note: There are two ways to create stored procedures: ISO/ANSI SQL and T-SQL. BEGIN TRANSACTION, for example, is T-SQL specific when using CREATE PROCEDURE syntax. Do not mix syntax when creating stored procedures. See CREATE PROCEDURE Statement [T-SQL].

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.

Side Effects
  • Automatic commit

Standards

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

Permissions

Must have RESOURCE authority, unless creating a temporary procedure. For external procedures or to create a procedure for another user, must have DBA authority.

Related reference
ALTER PROCEDURE Statement
BEGIN … END Statement
CALL Statement
CREATE PROCEDURE Statement
CREATE PROCEDURE Statement [T-SQL]
DROP Statement
EXECUTE IMMEDIATE Statement [ESQL] [SP]
GRANT Statement