A stored routine is either a procedure or a function. Stored
routines are created with CREATE PROCEDURE
and
CREATE FUNCTION
statements. A procedure is
invoked using a CALL
statement, and can only
pass back values using output variables. A function can be called
from inside a statement just like any other function (that is, by
invoking the function's name), and can return a scalar value.
Stored routines may call other stored routines.
As of MySQL 5.0.1, a stored procedure or function is associated with a particular database. This has several implications:
When the routine is invoked, an implicit USE
is performed (and
undone when the routine terminates). db_name
USE
statements within stored routines are disallowed.
You can qualify routine names with the database name. This can
be used to refer to a routine that is not in the current
database. For example, to invoke a stored procedure
p
or function f
that is
associated with the test
database, you can
say CALL test.p()
or
test.f()
.
When a database is dropped, all stored routines associated with it are dropped as well.
(In MySQL 5.0.0, stored routines are global and not associated
with a database. They inherit the default database from the
caller. If a USE
is executed within
the routine, the original default database is restored upon
routine exit.)
db_name
MySQL supports the very useful extension that allows the use of
regular SELECT
statements (that is, without
using cursors or local variables) inside a stored procedure. The
result set of such a query is simply sent directly to the client.
Multiple SELECT
statements generate multiple
result sets, so the client must use a MySQL client library that
supports multiple result sets. This means the client must use a
client library from a version of MySQL at least as recent as 4.1.
The client should also specify the
CLIENT_MULTI_STATEMENTS
option when it
connects. For C programs, this can be done with the
mysql_real_connect()
C API function (see
Section 22.2.3.51, “mysql_real_connect()
”).
The following sections describe the syntax used to create, alter, drop, and invoke stored procedures and functions.
CREATE [DEFINER = {user
| CURRENT_USER }] PROCEDUREsp_name
([proc_parameter
[,...]]) [characteristic
...]routine_body
CREATE [DEFINER = {user
| CURRENT_USER }] FUNCTIONsp_name
([func_parameter
[,...]]) RETURNStype
[characteristic
...]routine_body
proc_parameter
: [ IN | OUT | INOUT ]param_name
type
func_parameter
:param_name
type
type
:Any valid MySQL data type
characteristic
: LANGUAGE SQL | [NOT] DETERMINISTIC | { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA } | SQL SECURITY { DEFINER | INVOKER } | COMMENT 'string
'routine_body
:Valid SQL procedure statement
These statements create stored routines. As of MySQL 5.0.3, to
use them, it is necessary to have the CREATE
ROUTINE
privilege. If binary logging is enabled, these
statements might may also require the SUPER
privilege, as described in
Section 17.4, “Binary Logging of Stored Routines and Triggers”. MySQL automatically
grants the ALTER ROUTINE
and
EXECUTE
privileges to the routine creator.
By default, the routine is associated with the default database.
To associate the routine explicitly with a given database,
specify the name as db_name.sp_name
when you create it.
If the routine name is the same as the name of a built-in SQL function, you must use a space between the name and the following parenthesis when defining the routine, or a syntax error occurs. This is also true when you invoke the routine later. For this reason, we suggest that it is better to avoid re-using the names of existing SQL functions for your own stored routines.
The IGNORE_SPACE
SQL mode applies to built-in
functions, not to stored routines. it is always allowable to
have spaces after a routine name, regardless of whether
IGNORE_SPACE
is enabled.
The parameter list enclosed within parentheses must always be
present. If there are no parameters, an empty parameter list of
()
should be used. Each parameter is an
IN
parameter by default. To specify otherwise
for a parameter, use the keyword OUT
or
INOUT
before the parameter name.
Note: Specifying a parameter as
IN
, OUT
, or
INOUT
is valid only for a
PROCEDURE
. (FUNCTION
parameters are always regarded as IN
parameters.)
Each parameter can be declared to use any valid data type,
except that the COLLATE
attribute cannot be
used.
The RETURNS
clause may be specified only for
a FUNCTION
, for which it is mandatory. It
indicates the return type of the function, and the function body
must contain a RETURN
statement.
value
The routine_body
consists of a valid
SQL procedure statement. This can be a simple statement such as
SELECT
or INSERT
, or it
can be a compound statement written using
BEGIN
and END
. Compound
statement syntax is described in Section 17.2.5, “BEGIN ... END
Compound Statement Syntax”.
Compound statements can contain declarations, loops, and other
control structure statements. The syntax for these statements is
described later in this chapter. See, for example,
Section 17.2.6, “DECLARE
Statement Syntax”, and
Section 17.2.10, “Flow Control Constructs”. Some statements are
not allowed in stored routines; see
Section I.1, “Restrictions on Stored Routines and Triggers”.
The CREATE FUNCTION
statement was used in
earlier versions of MySQL to support UDFs (user-defined
functions). See Section 24.2, “Adding New Functions to MySQL”. UDFs
continue to be supported, even with the existence of stored
functions. A UDF can be regarded as an external stored function.
However, do note that stored functions share their namespace
with UDFs.
A procedure or function is considered
“deterministic” if it always produces the same
result for the same input parameters, and “not
deterministic” otherwise. If neither
DETERMINISTIC
nor NOT
DETERMINISTIC
is given in the routine definition, the
default is NOT DETERMINISTIC
.
A routine that contains the NOW()
function
(or its synonyms) or RAND()
is
non-deterministic, but it might still be replication-safe. For
NOW()
, the binary log includes the timestamp
and replicates correctly. RAND()
also
replicates correctly as long as it is invoked only once within a
routine. (You can consider the routine execution timestamp and
random number seed as implicit inputs that are identical on the
master and slave.)
Currently, the DETERMINISTIC
characteristic
is accepted, but not yet used by the optimizer. However, if
binary logging is enabled, this characteristic affects which
routine definitions MySQL accepts. See
Section 17.4, “Binary Logging of Stored Routines and Triggers”.
Several characteristics provide information about the nature of
data use by the routine. CONTAINS SQL
indicates that the routine does not contain statements that read
or write data. NO SQL
indicates that the
routine contains no SQL statements. READS SQL
DATA
indicates that the routine contains statements
that read data, but not statements that write data.
MODIFIES SQL DATA
indicates that the routine
contains statements that may write data. CONTAINS
SQL
is the default if none of these characteristics is
given explicitly. These characteristics are advisory only. The
server does not use them to constrain what kinds of statements a
routine will be allowed to execute.
The SQL SECURITY
characteristic can be used
to specify whether the routine should be executed using the
permissions of the user who creates the routine or the user who
invokes it. The default value is DEFINER
.
This feature is new in SQL:2003. The creator or invoker must
have permission to access the database with which the routine is
associated. As of MySQL 5.0.3, it is necessary to have the
EXECUTE
privilege to be able to execute the
routine. The user that must have this privilege is either the
definer or invoker, depending on how the SQL
SECURITY
characteristic is set.
The optional DEFINER
clause specifies the
MySQL account to be used when checking access privileges at
routine execution time for routines that have the SQL
SECURITY DEFINER
characteristic. The
DEFINER
clause was added in MySQL 5.0.20.
If a user
value is given, it should
be a MySQL account in
'
format (the same format used in the user_name
'@'host_name
'GRANT
statement). The user_name
and
host_name
values both are required.
CURRENT_USER
also can be given as
CURRENT_USER()
. The default
DEFINER
value is the user who executes the
CREATE PROCEDURE
or CREATE
FUNCTION
or statement. (This is the same as
DEFINER = CURRENT_USER
.)
If you specify the DEFINER
clause, you cannot
set the value to any account but your own unless you have the
SUPER
privilege. These rules determine the
legal DEFINER
user values:
If you do not have the SUPER
privilege,
the only legal user
value is your
own account, either specified literally or by using
CURRENT_USER
. You cannot set the definer
to some other account.
If you have the SUPER
privilege, you can
specify any syntactically legal account name. If the account
does not actually exist, a warning is generated.
Although it is possible to create routines with a
non-existent DEFINER
value, an error
occurs if the routine executes with definer privileges but
the definer does not exist at execution time.
MySQL stores the sql_mode
system variable
setting that is in effect at the time a routine is created, and
always executes the routine with this setting in force.
When the routine is invoked, an implicit USE
is performed (and
undone when the routine terminates). db_name
USE
statements within stored routines are disallowed.
As of MySQL 5.0.18, the server uses the data type of a routine
parameter or function return value as follows. These rules also
apply to local routine variables created with the
DECLARE
statement
(Section 17.2.7.1, “DECLARE
Local Variables”).
Assignments are checked for data type mismatches and overflow. Conversion and overflow problems result in warnings, or errors in strict mode.
For character data types, if there is a CHARACTER
SET
clause in the declaration, the specified
character set and its default collation are used. If there
is no such clause, the database character set and collation
are used. (These are given by the values of the
character_set_database
and
collation_database
system variables.)
Only scalar values can be assigned to parameters or
variables. For example, a statement such as SET x =
(SELECT 1, 2)
is invalid.
Before MySQL 5.0.18, parameters, return values, and local
variables are treated as items in expressions, and are subject
to automatic (silent) conversion and truncation. Stored
functions ignore the sql_mode
setting.
The COMMENT
clause is a MySQL extension, and
may be used to describe the stored routine. This information is
displayed by the SHOW CREATE PROCEDURE
and
SHOW CREATE FUNCTION
statements.
MySQL allows routines to contain DDL statements, such as
CREATE
and DROP
. MySQL
also allows stored procedures (but not stored functions) to
contain SQL transaction statements such as
COMMIT
. Stored functions may not contain
statements that do 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.
Stored routines cannot use LOAD DATA INFILE
.
Statements that return a result set cannot be used within a
stored function. This includes SELECT
statements that do not use INTO
to fetch
column values into variables, SHOW
statements, and other statements such as
EXPLAIN
. For statements that can be
determined at function definition time to return a result set, a
Not allowed to return a result set from a
function
error occurs
(ER_SP_NO_RETSET_IN_FUNC
). For statements
that can be determined only at runtime to return a result set, a
PROCEDURE %s can't return a result set in the given
context
error occurs
(ER_SP_BADSELECT
).
Note: 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
.
The following is an example of a simple stored procedure that
uses an OUT
parameter. The example uses the
mysql client delimiter
command to change the statement delimiter from
;
to //
while the
procedure is being defined. This allows the ;
delimiter used in the procedure body to be passed through to the
server rather than being interpreted by mysql
itself.
mysql>delimiter //
mysql>CREATE PROCEDURE simpleproc (OUT param1 INT)
->BEGIN
->SELECT COUNT(*) INTO param1 FROM t;
->END;
->//
Query OK, 0 rows affected (0.00 sec) mysql>delimiter ;
mysql>CALL simpleproc(@a);
Query OK, 0 rows affected (0.00 sec) mysql>SELECT @a;
+------+ | @a | +------+ | 3 | +------+ 1 row in set (0.00 sec)
When using the delimiter
command, you should
avoid the use of the backslash
(‘\
’) character because that is
the escape character for MySQL.
The following is an example of a function that takes a
parameter, performs an operation using an SQL function, and
returns the result. In this case, it is unnecessary to use
delimiter
because the function definition
contains no internal ;
statement delimiters:
mysql>CREATE FUNCTION hello (s CHAR(20)) RETURNS CHAR(50)
->RETURN CONCAT('Hello, ',s,'!');
Query OK, 0 rows affected (0.00 sec) mysql>SELECT hello('world');
+----------------+ | hello('world') | +----------------+ | Hello, world! | +----------------+ 1 row in set (0.00 sec)
A stored function returns a value of the data type specified in
its RETURNS
clause. If the
RETURN
statement returns a value of a
different type, the value is coerced to the proper type. For
example, if a function returns an ENUM
or
SET
value, but the RETURN
statement returns an integer, the value returned from the
function is the string for the corresponding
ENUM
member of set of SET
members.
ALTER {PROCEDURE | FUNCTION}sp_name
[characteristic
...]characteristic
: { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA } | SQL SECURITY { DEFINER | INVOKER } | COMMENT 'string
'
This statement can be used to change the characteristics of a
stored procedure or function. As of MySQL 5.0.3, you must have
the ALTER ROUTINE
privilege for the routine.
(That privilege is granted automatically to the routine
creator.) If binary logging is enabled, this statement might
also require the SUPER
privilege, as
described in Section 17.4, “Binary Logging of Stored Routines and Triggers”.
More than one change may be specified in an ALTER
PROCEDURE
or ALTER FUNCTION
statement.
DROP {PROCEDURE | FUNCTION} [IF EXISTS] sp_name
This statement is used to drop a stored procedure or function.
That is, the specified routine is removed from the server. As of
MySQL 5.0.3, you must have the ALTER ROUTINE
privilege for the routine. (That privilege is granted
automatically to the routine creator.)
The IF EXISTS
clause is a MySQL extension. It
prevents an error from occurring if the procedure or function
does not exist. A warning is produced that can be viewed with
SHOW WARNINGS
.
CALLsp_name
([parameter
[,...]])
The CALL
statement invokes a procedure that
was defined previously with CREATE PROCEDURE
.
CALL
can pass back values to its caller using
parameters that are declared as OUT
or
INOUT
parameters. It also
“returns” the number of rows affected, which a
client program can obtain at the SQL level by calling the
ROW_COUNT()
function and from C by calling
the mysql_affected_rows()
C API function.
If you write C programs that execute stored procedures with the
CALL
SQL statement, you
must set the
CLIENT_MULTI_RESULTS
flag when you call
mysql_real_connect()
, either explicitly, or
implicitly by setting
CLIENT_MULTI_STATEMENTS
. This is because each
CALL
returns a result to indicate the call
status, in addition to any results sets that might be returned
by statements executed within the procedure. To process the
result of a CALL
statement, use a loop that
calls mysql_next_result()
to determine
whether there are more results. For an example, see
Section 22.2.9, “C API Handling of Multiple Statement Execution”.
[begin_label
:] BEGIN [statement_list
] END [end_label
]
BEGIN ... END
syntax is used for writing
compound statements, which can appear within stored routines and
triggers. A compound statement can contain multiple statements,
enclosed by the BEGIN
and
END
keywords.
statement_list
represents a list of
one or more statements. Each statement within
statement_list
must be terminated by
a semicolon (;
) statement delimiter. Note
that statement_list
is optional,
which means that the empty compound statement (BEGIN
END
) is legal.
Use of multiple statements requires that a client is able to
send statement strings containing the ;
statement delimiter. This is handled in the
mysql command-line client with the
delimiter
command. Changing the
;
end-of-statement delimiter (for example, to
//
) allows ;
to be used in
a routine body. For an example, see
Section 17.2.1, “CREATE PROCEDURE
and CREATE
FUNCTION
Syntax”.
A compound statement can be labeled.
end_label
cannot be given unless
begin_label
also is present. If both
are present, they must be the same.
The optional [NOT] ATOMIC
clause is not yet
supported. This means that no transactional savepoint is set at
the start of the instruction block and the
BEGIN
clause used in this context has no
effect on the current transaction.
The DECLARE
statement is used to define
various items local to a routine:
Local variables. See Section 17.2.7, “Variables in Stored Routines”.
Conditions and handlers. See Section 17.2.8, “Conditions and Handlers”.
Cursors. See Section 17.2.9, “Cursors”.
The SIGNAL
and RESIGNAL
statements are not currently supported.
DECLARE
is allowed only inside a
BEGIN ... END
compound statement and must be
at its start, before any other statements.
Declarations must follow a certain order. Cursors must be declared before declaring handlers, and variables and conditions must be declared before declaring either cursors or handlers.
You may declare and use variables within a routine.
DECLAREvar_name
[,...]type
[DEFAULTvalue
]
This statement is used to declare local variables. To provide
a default value for the variable, include a
DEFAULT
clause. The value can be specified
as an expression; it need not be a constant. If the
DEFAULT
clause is missing, the initial
value is NULL
.
Local variables are treated like routine parameters with
respect to data type and overflow checking. See
Section 17.2.1, “CREATE PROCEDURE
and CREATE
FUNCTION
Syntax”.
The scope of a local variable is within the BEGIN ...
END
block where it is declared. The variable can be
referred to in blocks nested within the declaring block,
except those blocks that declare a variable with the same
name.
SETvar_name
=expr
[,var_name
=expr
] ...
The SET
statement in stored routines is an
extended version of the general SET
statement. Referenced variables may be ones declared inside a
routine, or global system variables.
The SET
statement in stored routines is
implemented as part of the pre-existing SET
syntax. This allows an extended syntax of SET a=x,
b=y, ...
where different variable types (locally
declared variables and global and session server variables)
can be mixed. This also allows combinations of local variables
and some options that make sense only for system variables; in
that case, the options are recognized but ignored.
SELECTcol_name
[,...] INTOvar_name
[,...]table_expr
This SELECT
syntax stores selected columns
directly into variables. Therefore, only a single row may be
retrieved.
SELECT id,data INTO x,y FROM test.t1 LIMIT 1;
User variable names are not case sensitive. See Section 9.3, “User-Defined Variables”.
Important: SQL variable names
should not be the same as column names. If an SQL statement,
such as a SELECT ... INTO
statement,
contains a reference to a column and a declared local variable
with the same name, MySQL currently interprets the reference
as the name of a variable. For example, in the following
statement, xname
is interpreted as a
reference to the xname
variable rather than the
xname
column:
CREATE PROCEDURE sp1 (x VARCHAR(5)) BEGIN DECLARE xname VARCHAR(5) DEFAULT 'bob'; DECLARE newname VARCHAR(5); DECLARE xid INT; SELECT xname,id INTO newname,xid FROM table1 WHERE xname = xname; SELECT newname; END;
When this procedure is called, the newname
variable returns the value 'bob'
regardless
of the value of the table1.xname
column.
See also Section I.1, “Restrictions on Stored Routines and Triggers”.
Certain conditions may require specific handling. These conditions can relate to errors, as well as to general flow control inside a routine.
DECLAREcondition_name
CONDITION FORcondition_value
condition_value
: SQLSTATE [VALUE]sqlstate_value
|mysql_error_code
This statement specifies conditions that need specific
handling. It associates a name with a specified error
condition. The name can subsequently be used in a
DECLARE HANDLER
statement. See
Section 17.2.8.2, “DECLARE
Handlers”.
A condition_value
can be an
SQLSTATE value or a MySQL error code.
DECLAREhandler_type
HANDLER FORcondition_value
[,...]statement
handler_type
: CONTINUE | EXIT | UNDOcondition_value
: SQLSTATE [VALUE]sqlstate_value
|condition_name
| SQLWARNING | NOT FOUND | SQLEXCEPTION |mysql_error_code
The DECLARE ... HANDLER
statement specifies
handlers that each may deal with one or more conditions. If
one of these conditions occurs, the specified
statement
is executed.
statement
can be a simple statement
(for example, SET
), or it can be a
compound statement written using var_name
= value
BEGIN
and
END
(see Section 17.2.5, “BEGIN ... END
Compound Statement Syntax”).
For a CONTINUE
handler, execution of the
current routine continues after execution of the handler
statement. For an EXIT
handler, execution
terminates for the BEGIN ... END
compound
statement in which the handler is declared. (This is true even
if the condition occurs in an inner block.) The
UNDO
handler type statement is not yet
supported.
If a condition occurs for which no handler has been declared,
the default action is EXIT
.
A condition_value
can be any of the
following values:
An SQLSTATE value or a MySQL error code.
A condition name previously specified with
DECLARE ... CONDITION
. See
Section 17.2.8.1, “DECLARE
Conditions”.
SQLWARNING
is shorthand for all
SQLSTATE codes that begin with 01
.
NOT FOUND
is shorthand for all SQLSTATE
codes that begin with 02
.
SQLEXCEPTION
is shorthand for all
SQLSTATE codes not caught by SQLWARNING
or NOT FOUND
.
Example:
mysql>CREATE TABLE test.t (s1 int,primary key (s1));
Query OK, 0 rows affected (0.00 sec) mysql>delimiter //
mysql>CREATE PROCEDURE handlerdemo ()
->BEGIN
->DECLARE CONTINUE HANDLER FOR SQLSTATE '23000' SET @x2 = 1;
->SET @x = 1;
->INSERT INTO test.t VALUES (1);
->SET @x = 2;
->INSERT INTO test.t VALUES (1);
->SET @x = 3;
->END;
->//
Query OK, 0 rows affected (0.00 sec) mysql>CALL handlerdemo()//
Query OK, 0 rows affected (0.00 sec) mysql>SELECT @x//
+------+ | @x | +------+ | 3 | +------+ 1 row in set (0.00 sec)
The example associates a handler with SQLSTATE 23000, which
occurs for a duplicate-key error. Notice that
@x
is 3
, which shows
that MySQL executed to the end of the procedure. If the line
DECLARE CONTINUE HANDLER FOR SQLSTATE '23000' SET @x2
= 1;
had not been present, MySQL would have taken
the default path (EXIT
) after the second
INSERT
failed due to the PRIMARY
KEY
constraint, and SELECT @x
would have returned 2
.
If you want to ignore a condition, you can declare a
CONTINUE
handler for it and associate it
with an empty block. For example:
DECLARE CONTINUE HANDLER FOR SQLWARNING BEGIN END;
Simple cursors are supported inside stored procedures and functions. The syntax is as in embedded SQL. Cursors are currently asensitive, read-only, and non-scrolling. Asensitive means that the server may or may not make a copy of its result table.
Cursors must be declared before declaring handlers, and variables and conditions must be declared before declaring either cursors or handlers.
Example:
CREATE PROCEDURE curdemo() BEGIN DECLARE done INT DEFAULT 0; DECLARE a CHAR(16); DECLARE b,c INT; DECLARE cur1 CURSOR FOR SELECT id,data FROM test.t1; DECLARE cur2 CURSOR FOR SELECT i FROM test.t2; DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET done = 1; OPEN cur1; OPEN cur2; REPEAT FETCH cur1 INTO a, b; FETCH cur2 INTO c; IF NOT done THEN IF b < c THEN INSERT INTO test.t3 VALUES (a,b); ELSE INSERT INTO test.t3 VALUES (a,c); END IF; END IF; UNTIL done END REPEAT; CLOSE cur1; CLOSE cur2; END
DECLAREcursor_name
CURSOR FORselect_statement
This statement declares a cursor. Multiple cursors may be declared in a routine, but each cursor in a given block must have a unique name.
The SELECT
statement cannot have an
INTO
clause.
The IF
, CASE
,
LOOP
, WHILE
,
REPLACE
ITERATE
, and
LEAVE
constructs are fully implemented.
Many of these constructs contain other statements, as indicated
by the grammar specifications in the following sections. Such
constructs may be nested. For example, an IF
statement might contain a WHILE
loop, which
itself contains a CASE
statement.
FOR
loops are not currently supported.
IFsearch_condition
THENstatement_list
[ELSEIFsearch_condition
THENstatement_list
] ... [ELSEstatement_list
] END IF
IF
implements a basic conditional
construct. If the search_condition
evaluates to true, the corresponding SQL statement list is
executed. If no search_condition
matches, the statement list in the ELSE
clause is executed. Each
statement_list
consists of one or
more statements.
Note: There is also an
IF()
function, which
differs from the IF
statement described here. See
Section 12.2, “Control Flow Functions”.
CASEcase_value
WHENwhen_value
THENstatement_list
[WHENwhen_value
THENstatement_list
] ... [ELSEstatement_list
] END CASE
Or:
CASE WHENsearch_condition
THENstatement_list
[WHENsearch_condition
THENstatement_list
] ... [ELSEstatement_list
] END CASE
The CASE
statement for stored routines
implements a complex conditional construct. If a
search_condition
evaluates to true,
the corresponding SQL statement list is executed. If no search
condition matches, the statement list in the
ELSE
clause is executed. Each
statement_list
consists of one or
more statements.
Note: The syntax of the
CASE
statement shown
here for use inside stored routines differs slightly from that
of the SQL CASE
expression described in
Section 12.2, “Control Flow Functions”. The
CASE
statement cannot have an ELSE
NULL
clause, and it is terminated with END
CASE
instead of END
.
[begin_label
:] LOOPstatement_list
END LOOP [end_label
]
LOOP
implements a simple loop construct,
enabling repeated execution of the statement list, which
consists of one or more statements. The statements within the
loop are repeated until the loop is exited; usually this is
accomplished with a LEAVE
statement.
A LOOP
statement can be labeled.
end_label
cannot be given unless
begin_label
also is present. If
both are present, they must be the same.
LEAVE label
This statement is used to exit any labeled flow control
construct. It can be used within BEGIN ...
END
or loop constructs (LOOP
,
REPEAT
, WHILE
).
ITERATE label
ITERATE
can appear only within
LOOP
, REPEAT
, and
WHILE
statements.
ITERATE
means “do the loop
again.”
Example:
CREATE PROCEDURE doiterate(p1 INT) BEGIN label1: LOOP SET p1 = p1 + 1; IF p1 < 10 THEN ITERATE label1; END IF; LEAVE label1; END LOOP label1; SET @x = p1; END
[begin_label
:] REPEATstatement_list
UNTILsearch_condition
END REPEAT [end_label
]
The statement list within a REPEAT
statement is repeated until the
search_condition
is true. Thus, a
REPEAT
always enters the loop at least
once. statement_list
consists of
one or more statements.
A REPEAT
statement can be labeled.
end_label
cannot be given unless
begin_label
also is present. If
both are present, they must be the same.
Example:
mysql>delimiter //
mysql>CREATE PROCEDURE dorepeat(p1 INT)
->BEGIN
->SET @x = 0;
->REPEAT SET @x = @x + 1; UNTIL @x > p1 END REPEAT;
->END
->//
Query OK, 0 rows affected (0.00 sec) mysql>CALL dorepeat(1000)//
Query OK, 0 rows affected (0.00 sec) mysql>SELECT @x//
+------+ | @x | +------+ | 1001 | +------+ 1 row in set (0.00 sec)
[begin_label
:] WHILEsearch_condition
DOstatement_list
END WHILE [end_label
]
The statement list within a WHILE
statement
is repeated as long as the
search_condition
is true.
statement_list
consists of one or
more statements.
A WHILE
statement can be labeled.
end_label
cannot be given unless
begin_label
also is present. If
both are present, they must be the same.
Example:
CREATE PROCEDURE dowhile() BEGIN DECLARE v1 INT DEFAULT 5; WHILE v1 > 0 DO ... SET v1 = v1 - 1; END WHILE; END