Some of the restrictions noted here apply to all stored routines; that is, both to stored procedures and stored functions. Some of these restrictions apply to stored functions but not to stored procedures.
The restrictions for stored functions also apply to triggers.
Stored routines cannot contain arbitrary SQL statements. The following statements are disallowed:
The table-maintenance statements CHECK
TABLE
and OPTIMIZE
TABLE
. This restriction is lifted beginning with
MySQL 5.0.17.
The locking statements LOCK
TABLES
and
UNLOCK
TABLES
.
ALTER VIEW
. (Before MySQL
5.0.46, this restriction is enforced only for stored
functions.)
LOAD DATA
and LOAD
TABLE
.
SQL prepared statements
(PREPARE
,
EXECUTE
,
DEALLOCATE PREPARE
).
Implication: You cannot use dynamic SQL within stored routines
(where you construct dynamically statements as strings and
then execute them). This restriction is lifted as of MySQL
5.0.13 for stored procedures; it still applies to stored
functions and triggers.
In addition, SQL statements that are not permitted within prepared statements are also not permitted in stored routines. See Section 12.6, “SQL Syntax for Prepared Statements”, for a list of statements supported as prepared statements. Statements not listed there are not supported for SQL prepared statements and thus are also not supported for stored routines unless noted otherwise in Section 18.2, “Using Stored Routines (Procedures and Functions)”.
Inserts cannot be delayed. INSERT
DELAYED
syntax is accepted but the statement is
handled as a normal INSERT
.
Within stored programs (stored procedures and functions, and
triggers), the parser treats
BEGIN [WORK]
as the beginning of a
BEGIN ...
END
block. Begin a transaction in this context with
START
TRANSACTION
instead.
For stored functions (but not stored procedures), the following additional statements or operations are disallowed:
Statements that perform explicit or implicit commit or rollback. Support for these statements is not required by the SQL standard, which states that each DBMS vendor may decide whether to allow them.
Statements that return a result set. This includes
SELECT
statements that do not
have an INTO
clause and other
statements such as var_list
SHOW
,
EXPLAIN
, and
CHECK TABLE
. A function can
process a result set either with SELECT ... INTO
or by using a
cursor and var_list
FETCH
statements.
See Section 12.7.3.3, “SELECT ... INTO
Statement”.
FLUSH
statements.
Before MySQL 5.0.10, stored functions created with
CREATE FUNCTION
must not
contain references to tables, with limited exceptions. They
may include some SET
statements that
contain table references, for example SET a:= (SELECT
MAX(id) FROM t)
, and
SELECT
statements that fetch
values directly into variables, for example SELECT i
INTO var1 FROM t
.
Stored functions cannot be used recursively.
Within a stored function or trigger, it is not permitted to modify a table that is already being used (for reading or writing) by the statement that invoked the function or trigger.
If you refer to a temporary table multiple times in a stored
function under different aliases, a Can't reopen
table:
'
error occurs, even if the references occur in different
statements within the function.
tbl_name
'
A stored function acquires table locks before executing, to avoid inconsistency in the binary log due to mismatch of the order in which statements execute and when they appear in the log. Statements that invoke a function are recorded rather than the statements executed within the function. Consequently, stored functions that update the same underlying tables do not execute in parallel. In contrast, stored procedures do not acquire table-level locks. All statements executed within stored procedures are written to the binary log. See Section 18.5, “Binary Logging of Stored Programs”.
Although some restrictions normally apply to stored functions and
triggers but not to stored procedures, those restrictions do apply
to stored procedures if they are invoked from within a stored
function or trigger. For example, if you use
FLUSH
in a stored procedure, that
stored procedure cannot be called from a stored function or
trigger.
It is possible for the same identifier to be used for a routine parameter, a local variable, and a table column. Also, the same local variable name can be used in nested blocks. For example:
CREATE PROCEDURE p (i INT) BEGIN DECLARE i INT DEFAULT 0; SELECT i FROM t; BEGIN DECLARE i INT DEFAULT 1; SELECT i FROM t; END; END;
In such cases the identifier is ambiguous and the following precedence rules apply:
A local variable takes precedence over a routine parameter or table column
A routine parameter takes precedence over a table column
A local variable in an inner block takes precedence over a local variable in an outer block
The behavior that variables take precedence over table columns is nonstandard.
Use of stored routines can cause replication problems. This issue is discussed further in Section 18.5, “Binary Logging of Stored Programs”.
INFORMATION_SCHEMA
does not have a
PARAMETERS
table until MySQL 5.5, so
applications that need to acquire routine parameter information at
runtime must use workarounds such as parsing the output of
SHOW CREATE
statements or the
param_list
column of the
mysql.proc
table. param_list
contents can be processed from within a stored routine, unlike the
output from SHOW
.
The
--replicate-wild-do-table=
option applies to tables, views, and triggers. It does not apply
to stored functions and procedures, or events. To filter
statements operating on the latter objects, use one or more of the
db_name.tbl_name
--replicate-*-db
options.
There are no stored routine debugging facilities.
Before MySQL 5.0.17, CALL
statements cannot be prepared. This true both for server-side
prepared statements and for SQL prepared statements.
UNDO
handlers are not supported.
FOR
loops are not supported.
To prevent problems of interaction between server threads, when a client issues a statement, the server uses a snapshot of routines and triggers available for execution of the statement. That is, the server calculates a list of procedures, functions, and triggers that may be used during execution of the statement, loads them, and then proceeds to execute the statement. This means that while the statement executes, it will not see changes to routines performed by other threads.
For triggers, the following additional statements or operations are disallowed:
User Comments
Add your own comment.