“Executable” Stored Procedure
The EXECUTE PROCEDURE
statement is most commonly used to invoke “executable” stored procedures to perform some data-modifying task at the server side — those that do not contain any SUSPEND
statements in their code.They can be designed to return a result set, consisting of only one row, which is usually passed, via a set of RETURNING_VALUES()
variables, to another stored procedure that calls it.Client interfaces usually have an API wrapper that can retrieve the output values into a single-row buffer when calling EXECUTE PROCEDURE
in DSQL.
Invoking “selectable” stored procedures is also possible with EXECUTE PROCEDURE
, but it returns only the first row of an output set which is almost surely designed to be multi-row.Selectable stored procedures are designed to be invoked by a SELECT
statement, producing output that behaves like a virtual table.
Note
|
|
Examples of EXECUTE PROCEDURE
-
In PSQL, with optional colons and without optional parentheses:
EXECUTE PROCEDURE MakeFullName :FirstName, :MiddleName, :LastName RETURNING_VALUES :FullName;
-
In Firebird’s command-line utility isql, with literal parameters and optional parentheses:
EXECUTE PROCEDURE MakeFullName ('J', 'Edgar', 'Hoover');
NoteIn DSQL (e.g. in isql),
RETURNING_VALUES
is not used.Any output values are captured by the application and displayed automatically. -
A PSQL example with expression parameters and optional parentheses:
EXECUTE PROCEDURE MakeFullName ('Mr./Mrs. ' || FirstName, MiddleName, upper(LastName)) RETURNING_VALUES (FullName);