Table of Contents
CREATE PROCEDURE
and CREATE FUNCTION
ALTER PROCEDURE
and ALTER FUNCTION
DROP PROCEDURE
and DROP FUNCTION
SHOW CREATE PROCEDURE
and SHOW CREATE FUNCTION
SHOW PROCEDURE STATUS
and SHOW FUNCTION STATUS
CALL
StatementBEGIN ... END
Compound StatementDECLARE
StatementStored procedures and functions are supported in MySQL version 5.0. A stored procedure is a set of SQL statements that can be stored in the server. Once this has been done, clients don't need to keep reissuing the individual statements but can refer to the stored procedure instead.
Some situations where stored procedures can be particularly useful:
When multiple client applications are written in different languages or work on different platforms, but need to perform the same database operations.
When security is paramount. Banks, for example, use stored procedures for all common operations. This provides a consistent and secure environment, and procedures can ensure that each operation is properly logged. In such a setup, applications and users would not get any access to the database tables directly, but can only execute specific stored procedures.
Stored procedures can provide improved performance because less information needs to be sent between the server and the client. The tradeoff is that this does increase the load on the database server system because more of the work is done on the server side and less is done on the client (application) side. Consider this if many client machines (such as Web servers) are serviced by only one or a few database servers.
Stored procedures also allow you to have libraries of functions in the database server. This is a feature shared by modern application languages that allow such design internally, for example, by using classes. Using these client application language features is beneficial for the programmer even outside the scope of database use.
MySQL follows the SQL:2003 syntax for stored procedures, which is also used by IBM's DB2.
The MySQL implementation of stored procedures is still in progress. All syntax described in this chapter is supported and any limitations and extensions are documented where appropriate. Further discussion of restrictions on use of stored procedures is given in Appendix I, Feature Restrictions.
Binary logging for stored routines is done as described in Section 18.4, “Binary Logging of Stored Routines and Triggers”.
Stored procedures require the proc
table in the
mysql
database. This table is created during
the MySQL 5.0 installation procedure. If you are
upgrading to MySQL 5.0 from an earlier version, be
sure to update your grant tables to make sure that the
proc
table exists. See
Section 2.10.3, “Upgrading the Grant Tables”.
Beginning with MySQL 5.0.3, the grant system has been modified to take stored routines into account as follows:
The CREATE ROUTINE
privilege is needed to
create stored routines.
The ALTER ROUTINE
privilege is needed to
alter or drop stored routines. This privilege is granted
automatically to the creator of a routine.
The EXECUTE
privilege is required to
execute stored routines. However, this privilege is granted
automatically to the creator of a routine. Also, the default
SQL SECURITY
characteristic for a routine
is DEFINER
, which allows users who have
access to the database with which the routine is associated to
execute the routine.
CREATE PROCEDURE
and CREATE FUNCTION
ALTER PROCEDURE
and ALTER FUNCTION
DROP PROCEDURE
and DROP FUNCTION
SHOW CREATE PROCEDURE
and SHOW CREATE FUNCTION
SHOW PROCEDURE STATUS
and SHOW FUNCTION STATUS
CALL
StatementBEGIN ... END
Compound StatementDECLARE
Statement
Stored procedures and functions are routines that are created with
CREATE PROCEDURE
and CREATE
FUNCTION
statements. A routine is either a procedure or
a function. 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 following sections describe the syntax used to create, alter, drop, and query stored procedures and functions.
CREATE PROCEDUREsp_name
([proc_parameter
[,...]]) [characteristic
...]routine_body
CREATE 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 or statements
These statements create stored routines. As of MySQL 5.0.3, to
create a routine, it is necessary to have the CREATE
ROUTINE
privilege, and the ALTER
ROUTINE
and EXECUTE
privileges are
granted automatically to its creator. If binary logging is
enabled, you may also need the SUPER
privilege, as described in
Section 18.4, “Binary Logging of Stored Routines and Triggers”.
By default, the routine is associated with the current 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 need to 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 — even though it is possible to do so — we suggest that it is better to avoid re-using the names of existing SQL functions for your own stored routines.
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.)
The RETURNS
clause may be specified only for
a FUNCTION
, for which it is mandatory. It is
used to indicate the return type of the function, and the
function body must contain a RETURN value
statement.
The routine_body
consists of valid
SQL procedure statements. Compound statement syntax can be used,
as described in Section 18.2.7, “BEGIN ... END
Compound Statement”. 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 18.2.8, “DECLARE
Statement” and
Section 18.2.12, “Flow Control Constructs”
The CREATE FUNCTION
statement was used in
earlier versions of MySQL to support UDFs (User Defined
Functions). See Section 25.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 framework for external stored procedures will be introduced in the near future. This will allow you to write stored procedures in languages other than SQL. Most likely, one of the first languages to be supported is PHP because the core PHP engine is small, thread-safe, and can easily be embedded. Because the framework is public, it is expected that many other languages can also be supported.
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, the default is NOT
DETERMINISTIC
.
For replication purposes, use of the NOW()
function (or its synonyms) or RAND()
does not
necessarily make a routine non-deterministic. 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 whether
MySQL accepts routine definitions. See
Section 18.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 the 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.
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.
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.
The COMMENT
clause is a MySQL extension, and
may be used to describe the stored procedure. 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 execeptions.
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:
mysql>delimiter //
mysql>CREATE FUNCTION hello (s CHAR(20)) RETURNS CHAR(50)
->RETURN CONCAT('Hello, ',s,'!');
->//
Query OK, 0 rows affected (0.00 sec) mysql>delimiter ;
mysql>SELECT hello('world');
+----------------+ | hello('world') | +----------------+ | Hello, world! | +----------------+ 1 row in set (0.00 sec)
If the RETURN
statement in a stored function
returns a value that has a different type than is specified in
the function's RETURNS
clause, the return
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. You must have the ALTER
ROUTINE
privilege for the routine as of MySQL 5.0.3.
This privilege is granted automatically to the routine creator.
If binary logging is enabled, you may also need the
SUPER
privilege, as described in
Section 18.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. You
must have the ALTER ROUTINE
privilege for the
routine as of MySQL 5.0.3. This 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
.
SHOW CREATE {PROCEDURE | FUNCTION} sp_name
This statement is a MySQL extension. Similar to SHOW
CREATE TABLE
, it returns the exact string that can be
used to re-create the named routine.
mysql> SHOW CREATE FUNCTION test.hello\G
*************************** 1. row ***************************
Function: hello
sql_mode:
Create Function: CREATE FUNCTION `test`.`hello`(s CHAR(20)) RETURNS CHAR(50)
RETURN CONCAT('Hello, ',s,'!')
SHOW {PROCEDURE | FUNCTION} STATUS [LIKE 'pattern
']
This statement is a MySQL extension. It returns characteristics of routines, such as the database, name, type, creator, and creation and modification dates. If no pattern is specified, the information for all stored procedures or all stored functions is listed, depending on which statement you use.
mysql> SHOW FUNCTION STATUS LIKE 'hello'\G
*************************** 1. row ***************************
Db: test
Name: hello
Type: FUNCTION
Definer: testuser@localhost
Modified: 2004-08-03 15:29:37
Created: 2004-08-03 15:29:37
Security_type: DEFINER
Comment:
You can also get information about stored routines from the
ROUTINES
table in
INFORMATION_SCHEMA
. See
Section 21.1.14, “The INFORMATION_SCHEMA ROUTINES
Table”.
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.
[begin_label
:] BEGIN [statement_list
] END [end_label
]
Stored routines may contain multiple statements, using a
BEGIN ... END
compound statement.
statement_list
represents a list of
one or more statements. Each statement within
statement_list
must be terminated by
a semicolon character (;
).
A compound statement can be labeled.
end_label
cannot be given unless
begin_label
also is present, and if
both are present, they must be the same.
Please note that 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.
Using multiple statements requires that a client is able to send
query strings containing the ;
statement
delimiter. This is handled in the mysql
command-line client with the delimiter
command. Changing the ;
end-of-query
delimiter (for example, to //
) allows
;
to be used in a routine body.
The DECLARE
statement is used to define
various items local to a routine: local variables (see
Section 18.2.9, “Variables in Stored Procedures”), conditions
and handlers (see Section 18.2.10, “Conditions and Handlers”) and
cursors (see Section 18.2.11, “Cursors”).
SIGNAL
and RESIGNAL
statements are not currently supported.
DECLARE
may be used only inside a
BEGIN ... END
compound statement and must be
at its start, before any other statements.
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
.
The scope of a local variable is within the BEGIN ...
END
block where it is declared. It can be used in
nested blocks except those that declare a variable with the
same name.
SETvar_name
=expr
[,var_name
=expr
] ...
The SET
statement in stored procedures is
an extended version of the general SET
statement. Referenced variables may be ones declared inside a
routine, or global server variables.
The SET
statement in stored procedures 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;
Note that user variable names are not case sensitive in MySQL 5.0. See Section 9.3, “User 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 will return 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 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 18.2.10.2, “DECLARE
Handlers”.
In addition to SQLSTATE values, MySQL error codes are also supported.
DECLAREhandler_type
HANDLER FORcondition_value
[,...]sp_statement
handler_type
: CONTINUE | EXIT | UNDOcondition_value
: SQLSTATE [VALUE]sqlstate_value
|condition_name
| SQLWARNING | NOT FOUND | SQLEXCEPTION |mysql_error_code
This statement specifies handlers that each may deal with one or more conditions. If one of these conditions occurs, the specified statement is executed.
For a CONTINUE
handler, execution of the
current routine continues after execution of the handler
statement. For an EXIT
handler, execution
of the current BEGIN...END
compound
statement is terminated. The UNDO
handler
type statement is not yet supported.
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
.
In addition to SQLSTATE values, MySQL error codes are also supported.
For 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)
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 (EXIT
) path
after the second INSERT
failed due to the
PRIMARY KEY
constraint, and SELECT
@x
would have returned 2
.
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.
For 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 defined in a routine, but each cursor in a block must have a unique name.
The SELECT
statement cannot have an
INTO
clause.
The IF
, CASE
,
LOOP
, WHILE
,
ITERATE
, and LEAVE
constructs are fully implemented.
These constructs may each contain either a single statement, or
a block of statements using the BEGIN ... END
compound statement. Constructs may be nested.
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. statement_list
can consist of one or more statements.
Please note that 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 procedures
implements a complex conditional construct. If a
search_condition
evaluates to true,
the corresponding SQL statement is executed. If no search
condition matches, the statement in the
ELSE
clause is executed.
Note: The syntax of a
CASE
statement shown
here for use inside a stored procedure 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 a particular statement or
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, and 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 with BEGIN ...
END
or loops.
ITERATE label
ITERATE
can only appear within
LOOP
, REPEAT
, and
WHILE
statements.
ITERATE
means “do the loop
again.”
For 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 or statements within a REPEAT
statement are repeated until the
search_condition
is true.
A REPEAT
statement can be labeled.
end_label
cannot be given unless
begin_label
also is present, and if
both are present, they must be the same.
For 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 or statements within a WHILE
statement are repeated as long as the
search_condition
is true.
A WHILE
statement can be labeled.
end_label
cannot be given unless
begin_label
also is present, and if
both are present, they must be the same.
For example:
CREATE PROCEDURE dowhile() BEGIN DECLARE v1 INT DEFAULT 5; WHILE v1 > 0 DO ... SET v1 = v1 - 1; END WHILE; END
Do MySQL 5.0 stored procedures and functions work with replication?
Yes, standard actions carried out in stored procedures and functions are replicated from a master MySQL server to a slave server. There are a few limitations that are described in detail in Section 18.4, “Binary Logging of Stored Routines and Triggers”.
Are stored procedures and functions created on a master server replicated to a slave?
Yes, creation of stored procedures and functions carried out
through normal DDL statements on a master server are
replicated to a slave, so the objects will exist on both
servers. ALTER
and DROP
statements for stored procedures and functions are also
replicated.
How are actions that take place inside stored procedures and functions replicated?
MySQL records each DML event that occurs in a stored procedure and function and replicates those individual actions to a slave server. The actual calls made to execute stored procedures and functions are not replicated.
Are there special security requirements for using stored procedures, functions and replication together?
Yes. Because a slave server has authority to execute any statement read from a master's binary log, special security constraints exist for using stored procedures and functions with replication. If replication or binary logging in general (for the purpose of point-in-time recovery) is active, then MySQL DBAs have two security options open to them:
Any user wishing to create stored procedures must be
granted the SUPER
privilege.
Alternatively, a DBA can set the
log_bin_trust_routine_creators
system
variable to 1, which will allow anyone with the standard
CREATE ROUTINE
privilege to create
stored procedures and functions.
What limitations exist for replicating stored procedure and function actions?
Non-deterministic (random) or time-based actions embedded in
stored procedures may not replicate properly. By their very
nature, randomly produced results are not predictable and
cannot be exactly cloned, and therefore, random actions
replicated to a slave will not mirror those produced on a
master. Note that declaring stored procedures or functions to
be DETERMINISTIC
or setting the
log_bin_trust_routine_creators
system
variable to 0 will not allow random-valued operations to be
invoked.
In addition, time-based actions cannot be reproduced on a slave as the timing of such actions in a stored procedure is not reproducible through the binary log used for replication as it only records DML events and does not factor in timing constraints.
Finally, non-transactional tables for which errors occur
during large DML actions (such as bulk inserts) may experience
replication issues in that a master may be partially updated
from DML activity, but no updates are done to the slave
because of the errors that occurred. A workaround is for a
function's DML actions to be carried out with the
IGNORE
keyword so that updates on the
master that cause errors are ignored and updates that do not
cause errors are replicated to the slave.
Do the limitations described above affect MySQL's ability to do point-in-time recovery?
The same limitations that affect replication do affect point-in-time recovery.
What will MySQL do to correct the aforementioned limitations?
A future release of MySQL is expected to feature a choice in how replication should be handled:
Statement-based replication (current implementation).
Row-level replication (that will solve all the limitations described earlier).
Do triggers work with replication?
Triggers and replication in MySQL 5.0 work the same as in most other database engines in that actions carried out through triggers on a master are not replicated to a slave server. Instead, triggers that exist on tables that reside on a MySQL master server need to be created on the tables that exist on any MySQL slave servers so that the triggers activate on the slaves as well as the master.
How are actions carried out through triggers on a master replicated to a slave?
First, the triggers that exist on a master must be recreated
on the slave server. Once this is done, the replication flow
works as any other standard DML statement that participates in
replication. For example, consider a table
EMP
that has an AFTER
insert trigger, which exists on a master MySQL server. The
same EMP
table and AFTER
insert trigger exist on the slave server as well. The
replication flow would be:
An INSERT
statement is made to
EMP
.
The AFTER
trigger on EMP
activates.
The INSERT
statement is written to the
binary log.
The replication slave picks up the INSERT
statement to EMP
and executes it on the
slave.
The AFTER
trigger on EMP
that exists on the slave activates.
This section describes how MySQL 5.0 handles stored routines (procedures and functions) with respect to binary logging. This section also applies to triggers.
The binary log contains information about SQL statements that modify database contents. This information is stored in the form of “events” that describe the modifications.
The binary log has two important purposes:
The basis for replication is that the master server sends the events contained in its binary log to its slaves, which execute those events to make the same data changes that were made on the master. See Section 6.2, “Replication Implementation Overview”.
Certain data recovery operations require use of the binary log. After a backup file has been restored, the events in the binary log that were recorded after the backup was made are re-executed. These events bring databases up to date from the point of the backup. See Section 5.9.2.2, “Using Backups for Recovery”.
Stored routine logging differs before and after MySQL 5.0.6. Before MySQL 5.0.6, statements that create and use stored routines are not written to the binary log, but statements invoked within stored routines are logged. Suppose that you issue the following statements:
CREATE PROCEDURE mysp INSERT INTO t VALUES(1); CALL mysp;
For this example, only the INSERT
statement
will appear in the binary log. The CREATE
PROCEDURE
and CALL
statements will
not appear. The absence of routine-related statements in the
binary log means that stored routines are not replicated
correctly. It also means that for a data recovery operation,
re-executing events in the binary log does not recover stored
routines.
To address these replication and data recovery concerns, binary logging for stored routines was changed in MySQL 5.0.6. However, this change also raises new issues, which are presented in the following discussion for your information.
Except as noted otherwise, these remarks assume that you have
enabled binary logging by starting the server with the
--log-bin
option. (If the binary log is not
enabled, replication is not possible, nor is the binary log
available for data recovery.) See Section 5.11.3, “The Binary Log”.
The characteristics of binary logging for stored routine statements are described in the following list. Some of the items indicate problems of which you should be aware, but in some cases, there are server settings that you can modify or workarounds that you can use to deal with them.
The CREATE PROCEDURE
, CREATE
FUNCTION
, ALTER PROCEDURE
, and
ALTER FUNCTION
statements are written to
the binary log, as are CALL
, DROP
PROCEDURE
, and DROP FUNCTION
.
However, there is a security implication for replication: To
create a routine, a user must have the CREATE
ROUTINE
privilege, but a user who has this privilege
could write a routine to perform any action on a slave server
because the SQL thread on the slave runs with full privileges.
For example, if the master and slave servers have server ID
values of 1 and 2, respectively, a user on the master server
could create and invoke a procedure as follows:
mysql>delimiter //
mysql>CREATE PROCEDURE mysp ()
->BEGIN
->IF @@server_id=2 THEN DROP DATABASE accounting; END IF;
->END;
->//
mysql>delimiter ;
mysql>CALL mysp();
The CREATE PROCEDURE
and
CALL
statements will be written to the
binary log, so the slave will execute them. Because the slave
SQL thread has full privileges, it will drop the
accounting
database.
To avoid this danger for servers that have binary logging
enabled, MySQL 5.0.6 introduces the requirement that stored
procedure and function creators must have the
SUPER
privilege, in addition to the usual
CREATE ROUTINE
privilege that is required.
Similarly, to use ALTER PROCEDURE
or
ALTER FUNCTION
, you must have the
SUPER
privilege in addition to the
ALTER ROUTINE
privilege. Without the
SUPER
privilege, an error will occur:
ERROR 1419 (HY000): You do not have the SUPER privilege and binary logging is enabled (you *might* want to use the less safe log_bin_trust_routine_creators variable)
You might not want to enforce the requirement on routine
creators that they must have the SUPER
privilege. For example, all users with the CREATE
ROUTINE
privilege on your system might be
experienced application developers. To disable the requirement
for SUPER
, set the global
log_bin_trust_routine_creators
system
variable to 1. By default, this variable has a value of 0, but
you can change it like this:
mysql> SET GLOBAL log_bin_trust_routine_creators = 1;
You can also enable this variable by using the
--log-bin-trust-routine-creators
option when
starting the server.
If binary logging is not enabled,
log_bin_trust_routine_creators
does not
apply and SUPER
is not required for routine
creation.
A non-deterministic routine that performs updates is not repeatable, which can have two undesirable effects:
It will make a slave different from the master.
Restored data will be different from the original data.
To deal with these problems, MySQL enforces the following requirement: On a master server, creation and alteration of a routine is refused unless the routine is declared to be deterministic or to not modify data. This means that when you create a routine, you must declare either that it is deterministic or that it does not change data. Two sets of routine characteristics apply here:
DETERMINISTIC
and NOT
DETERMINISTIC
indicate whether a routine always
produces the same result for given inputs. The default is
NOT DETERMINISTIC
if neither
characteristic is given, so you must specify
DETERMINISTIC
explicitly to declare
that a routine is deterministic.
Use of the NOW()
function (or its
synonyms) or RAND()
does not
necessarily make a routine non-deterministic. 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.)
CONTAINS SQL
, NO
SQL
, READS SQL DATA
, and
MODIFIES SQL
data provide information
about whether the routine reads or writes data. Either
NO SQL
or READS SQL
DATA
indicates that a routine does not change
data, but you must specify one of these explicitly because
the default is CONTAINS SQL
if none of
these characteristics is given.
By default, for a CREATE PROCEDURE
or
CREATE FUNCTION
statement to be accepted,
DETERMINISTIC
or one of NO
SQL
and READS SQL DATA
must be
explicitly specified. Otherwise an error occurs:
ERROR 1418 (HY000): This routine has none of DETERMINISTIC, NO SQL, or READS SQL DATA in its declaration and binary logging is enabled (you *might* want to use the less safe log_bin_trust_routine_creators variable)
If you set log_bin_trust_routine_creators
to 1, the requirement that routines be deterministic or not
modify data is dropped.
Note that assessment of the nature of a routine is based on
the “honesty” of the creator: MySQL does not
check that a routine declared DETERMINISTIC
contains no statements that produce non-deterministic results.
A CALL
statement is written to the binary
log if the routine returns no error, but not otherwise. When a
routine that modifies data fails, you get this warning:
ERROR 1417 (HY000): A routine failed and has neither NO SQL nor READS SQL DATA in its declaration and binary logging is enabled; if non-transactional tables were updated, the binary log will miss their changes
This logging behavior has the potential to cause problems. If
a routine partly modifies a non-transactional table (such as a
MyISAM
table) and returns an error, the
binary log will not reflect these changes. To protect against
this, you should use transactional tables in the routine and
modify the tables within transactions.
If you use the IGNORE
keyword with
INSERT
, DELETE
, or
UPDATE
to ignore errors within a routine, a
partial update might occur but no error will result. Such
statements are logged and replicate normally.
If a stored function is invoked within a statement such as
SELECT
that does not modify data, execution
of the function will not be written to the binary log, even if
the function itself modifies data. This logging behavior has
the potential to cause problems. Suppose that a function
myfunc()
is defined as follows:
CREATE FUNCTION myfunc () RETURNS INT BEGIN INSERT INTO t (i) VALUES(1); RETURN 0; END;
Given that definition, the following statement modifies the
table t
because myfunc()
modifies t
, but the statement is not
written to the binary log because it is a
SELECT
:
SELECT myfunc();
A workaround for this problem is to invoke functions that do
updates within statements that do updates. Note that although
the DO
statement sometimes is executed for
the side effect of evaluating an expression,
DO
is not a workaround here because it is
not written to the binary log.
The statements executed within a routine are not written to the binary log. Suppose that you issue the following statements:
CREATE PROCEDURE mysp INSERT INTO t VALUES(1); CALL mysp;
For this example, the CREATE PROCEDURE
and
CALL
statements appear in the binary log,
but the INSERT
statement does not appear.
This corrects the problem that occurred before MySQL 5.0.6 in
which the CREATE PROCEDURE
and
CALL
statements were not logged and the
INSERT
was logged.
On slave servers, the following limitation is applied when
determining which events from the master replicate:
--replicate-*-table
rules don't apply to
CALL
statements or to statements within
routines: The rules in these cases always return “do
replicate!”
Triggers are similar to stored functions, so the preceding remarks
also apply to triggers with the following exception:
CREATE TRIGGER
does not have an optional
DETERMINISTIC
characteristic, so triggers are
assumed to be always deterministic. However, this assumption might
in some cases be invalid. For example, the
UUID()
function is non-deterministic (and does
not replicate). You should be careful about using such functions
in triggers.
Triggers currently can't update tables, but they will in the
future. For this reason, error messages similar to those for
stored routines occur with CREATE TRIGGER
if
you do not have the SUPER
privilege and
log_bin_trust_routine_creators
is 0.
The issues described in this section result from the fact that binary logging occurs at the SQL statement level. A future MySQL release is expected to implement row-level binary logging, which occurs at a more fine-grained level and specifies which changes to make to individual records as a result of executing SQL statements.