17.2. Stored Routine Syntax

MySQL 5.0

17.2. Stored Routine Syntax

A stored routine is either a procedure or a function. Stored routines are created with and statements. A procedure is invoked using a 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 is performed (and undone when the routine terminates). 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 or function that is associated with the database, you can say or .

  • 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 is executed within the routine, the original default database is restored upon routine exit.)

MySQL supports the very useful extension that allows the use of regular 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 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 option when it connects. For C programs, this can be done with the C API function (see Section 22.2.3.51, “).

The following sections describe the syntax used to create, alter, drop, and invoke stored procedures and functions.

17.2.1. CREATE PROCEDURE and CREATE FUNCTION Syntax

CREATE
    [DEFINER = {  | CURRENT_USER }]
    PROCEDURE  ([[,...]])
    [ ...] 

CREATE
    [DEFINER = {  | CURRENT_USER }]
    FUNCTION  ([[,...]])
    RETURNS 
    [ ...] 
    
:
    [ IN | OUT | INOUT ]  
    
:
     

:
    

:
    LANGUAGE SQL
  | [NOT] DETERMINISTIC
  | { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA }
  | SQL SECURITY { DEFINER | INVOKER }
  | COMMENT ''

:
    

These statements create stored routines. As of MySQL 5.0.3, to use them, it is necessary to have the privilege. If binary logging is enabled, these statements might may also require the privilege, as described in Section 17.4, “Binary Logging of Stored Routines and Triggers”. MySQL automatically grants the and 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 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 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 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 can be declared to use any valid data type, except that the attribute cannot be used.

Each parameter is an parameter by default. To specify otherwise for a parameter, use the keyword or before the parameter name.

Note: Specifying a parameter as , , or is valid only for a . ( parameters are always regarded as parameters.)

An parameter passes a value into a procedure. The procedure might modify the value, but the modification is not visible to the caller when the procedure returns. An parameter passes a value from the procedure back to the caller. Its initial value is within the procedure, and its value is visible to the caller when the procedure returns. An parameter is initialized by the caller, can be modified by the procedure, and any change made by the procedure is visible to the caller when the procedure returns.

For each or parameter, pass a user-defined variable so that you can obtain its value when the procedure returns. (For an example, see Section 17.2.4, “ Statement Syntax”.) If you are calling the procedure from within another stored procedure or function, you can also pass a routine parameter or local routine variable as an or parameter.

The clause may be specified only for a , for which it is mandatory. It indicates the return type of the function, and the function body must contain a statement.

The consists of a valid SQL procedure statement. This can be a simple statement such as or , or it can be a compound statement written using and . Compound statement syntax is described in Section 17.2.5, “ 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, “ 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 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 nor is given in the routine definition, the default is .

A routine that contains the function (or its synonyms) or is non-deterministic, but it might still be replication-safe. For , the binary log includes the timestamp and replicates correctly. 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 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. indicates that the routine does not contain statements that read or write data. indicates that the routine contains no SQL statements. indicates that the routine contains statements that read data, but not statements that write data. indicates that the routine contains statements that may write data. 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 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 . 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 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 characteristic is set.

The optional clause specifies the MySQL account to be used when checking access privileges at routine execution time for routines that have the characteristic. The clause was added in MySQL 5.0.20.

If a value is given, it should be a MySQL account in '@'' format (the same format used in the statement). The and values both are required. also can be given as . The default value is the user who executes the or or statement. (This is the same as .)

If you specify the clause, you cannot set the value to any account but your own unless you have the privilege. These rules determine the legal user values:

  • If you do not have the privilege, the only legal value is your own account, either specified literally or by using . You cannot set the definer to some other account.

  • If you have the 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 value, an error occurs if the routine executes with definer privileges but the definer does not exist at execution time.

MySQL stores the 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 is performed (and undone when the routine terminates). 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 statement (Section 17.2.7.1, “ 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 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 and system variables.)

  • Only scalar values can be assigned to parameters or variables. For example, a statement such as 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 setting.

The clause is a MySQL extension, and may be used to describe the stored routine. This information is displayed by the and statements.

MySQL allows routines to contain DDL statements, such as and . MySQL also allows stored procedures (but not stored functions) to contain SQL transaction statements such as . 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 .

Statements that return a result set cannot be used within a stored function. This includes statements that do not use to fetch column values into variables, statements, and other statements such as . For statements that can be determined at function definition time to return a result set, a error occurs (). For statements that can be determined only at runtime to return a result set, a error occurs ().

Note: Before MySQL 5.0.10, stored functions created with must not contain references to tables, with limited exceptions. They may include some statements that contain table references, for example , and statements that fetch values directly into variables, for example .

The following is an example of a simple stored procedure that uses an parameter. The example uses the mysql client 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> 

mysql> 
    -> 
    ->   
    -> 
    -> 
Query OK, 0 rows affected (0.00 sec)

mysql> 

mysql> 
Query OK, 0 rows affected (0.00 sec)

mysql> 
+------+
| @a   |
+------+
| 3    |
+------+
1 row in set (0.00 sec)

When using the 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 because the function definition contains no internal statement delimiters:

mysql> 
    -> 
Query OK, 0 rows affected (0.00 sec)

mysql> 
+----------------+
| hello('world') |
+----------------+
| Hello, world!  |
+----------------+
1 row in set (0.00 sec)

A stored function returns a value of the data type specified in its clause. If the statement returns a value of a different type, the value is coerced to the proper type. For example, if a function returns an or value, but the statement returns an integer, the value returned from the function is the string for the corresponding member of set of members.

17.2.2. ALTER PROCEDURE and ALTER FUNCTION Syntax

ALTER {PROCEDURE | FUNCTION}  [ ...]

:
    { CONTAINS SQL | NO SQL | READS SQL DATA | MODIFIES SQL DATA }
  | SQL SECURITY { DEFINER | INVOKER }
  | COMMENT ''

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 privilege for the routine. (That privilege is granted automatically to the routine creator.) If binary logging is enabled, this statement might also require the privilege, as described in Section 17.4, “Binary Logging of Stored Routines and Triggers”.

More than one change may be specified in an or statement.

17.2.3. DROP PROCEDURE and DROP FUNCTION Syntax

DROP {PROCEDURE | FUNCTION} [IF EXISTS] 

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 privilege for the routine. (That privilege is granted automatically to the routine creator.)

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

17.2.4. CALL Statement Syntax

CALL ([[,...]])

The statement invokes a procedure that was defined previously with .

can pass back values to its caller using parameters that are declared as or parameters. It also “returns” the number of rows affected, which a client program can obtain at the SQL level by calling the function and from C by calling the C API function.

To get back a value from a procedure using an or parameter, pass the parameter by means of a user variable, and then check the value of the variable after the procedure returns. (If you are calling the procedure from within another stored procedure or function, you can also pass a routine parameter or local routine variable as an or parameter.) For an parameter, initialize its value before passing it to the procedure. The following procedure has an parameter that the procedure sets to the current server version, and an value that the procedure increments by one from its current value:

CREATE PROCEDURE p (OUT ver_param VARCHAR(25), INOUT incr_param INT)
BEGIN
  # Set value of OUT parameter
  SELECT VERSION() INTO ver_param;
  # Increment value of INOUT parameter
  SET incr_param = incr_param + 1;
END;

Before calling the procedure, initialize the variable to be passed as the parameter. After calling the procedure, the values of the two variables will have been set or modified:

mysql> 
mysql> 
mysql> 
+------------+------------+
| @version   | @increment |
+------------+------------+
| 5.0.25-log | 11         | 
+------------+------------+

If you write C programs that execute stored procedures with the SQL statement, you must set the flag when you call , either explicitly, or implicitly by setting . This is because each 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 statement, use a loop that calls to determine whether there are more results. For an example, see Section 22.2.9, “C API Handling of Multiple Statement Execution”.

17.2.5. BEGIN ... END Compound Statement Syntax

[:] 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 and keywords. represents a list of one or more statements. Each statement within must be terminated by a semicolon () statement delimiter. Note that is optional, which means that the empty compound statement () 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 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, “ and Syntax”.

A compound statement can be labeled. cannot be given unless also is present. If both are present, they must be the same.

The optional clause is not yet supported. This means that no transactional savepoint is set at the start of the instruction block and the clause used in this context has no effect on the current transaction.

17.2.6. DECLARE Statement Syntax

The statement is used to define various items local to a routine:

The and statements are not currently supported.

is allowed only inside a 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.

17.2.7. Variables in Stored Routines

You may declare and use variables within a routine.

17.2.7.1.  Local Variables

DECLARE [,...]  [DEFAULT ]

This statement is used to declare local variables. To provide a default value for the variable, include a clause. The value can be specified as an expression; it need not be a constant. If the clause is missing, the initial value is .

Local variables are treated like routine parameters with respect to data type and overflow checking. See Section 17.2.1, “ and Syntax”.

The scope of a local variable is within the 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.

17.2.7.2. Variable Statement

SET  =  [,  = ] ...

The statement in stored routines is an extended version of the general statement. Referenced variables may be ones declared inside a routine, or global system variables.

The statement in stored routines is implemented as part of the pre-existing syntax. This allows an extended syntax of 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.

17.2.7.3.  Statement

SELECT [,...] INTO [,...] 

This 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 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, is interpreted as a reference to the variable rather than the 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 variable returns the value regardless of the value of the column.

See also Section I.1, “Restrictions on Stored Routines and Triggers”.

17.2.8. Conditions and Handlers

Certain conditions may require specific handling. These conditions can relate to errors, as well as to general flow control inside a routine.

17.2.8.1.  Conditions

DECLARE  CONDITION FOR 

:
    SQLSTATE [VALUE] 
  | 

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 statement. See Section 17.2.8.2, “ Handlers”.

A can be an SQLSTATE value or a MySQL error code.

17.2.8.2.  Handlers

DECLARE  HANDLER FOR [,...] 

:
    CONTINUE
  | EXIT
  | UNDO

:
    SQLSTATE [VALUE] 
  | 
  | SQLWARNING
  | NOT FOUND
  | SQLEXCEPTION
  | 

The statement specifies handlers that each may deal with one or more conditions. If one of these conditions occurs, the specified is executed. can be a simple statement (for example, = ), or it can be a compound statement written using and (see Section 17.2.5, “ Compound Statement Syntax”).

For a handler, execution of the current routine continues after execution of the handler statement. For an handler, execution terminates for the compound statement in which the handler is declared. (This is true even if the condition occurs in an inner block.) The handler type statement is not yet supported.

If a condition occurs for which no handler has been declared, the default action is .

A can be any of the following values:

  • An SQLSTATE value or a MySQL error code.

  • A condition name previously specified with . See Section 17.2.8.1, “ Conditions”.

  • is shorthand for all SQLSTATE codes that begin with .

  • is shorthand for all SQLSTATE codes that begin with .

  • is shorthand for all SQLSTATE codes not caught by or .

Example:

mysql> 
Query OK, 0 rows affected (0.00 sec)

mysql> 

mysql> 
    -> 
    ->   
    ->   
    ->   
    ->   
    ->   
    ->   
    -> 
    -> 
Query OK, 0 rows affected (0.00 sec)

mysql> 
Query OK, 0 rows affected (0.00 sec)

mysql> 
    +------+
    | @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 is , which shows that MySQL executed to the end of the procedure. If the line had not been present, MySQL would have taken the default path () after the second failed due to the constraint, and would have returned .

If you want to ignore a condition, you can declare a handler for it and associate it with an empty block. For example:

DECLARE CONTINUE HANDLER FOR SQLWARNING BEGIN END;

17.2.9. Cursors

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

17.2.9.1. Declaring Cursors

DECLARE  CURSOR FOR 

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 statement cannot have an clause.

17.2.9.2. Cursor Statement

OPEN 

This statement opens a previously declared cursor.

17.2.9.3. Cursor Statement

FETCH  INTO  [, ] ...

This statement fetches the next row (if a row exists) using the specified open cursor, and advances the cursor pointer.

17.2.9.4. Cursor Statement

CLOSE 

This statement closes a previously opened cursor.

If not closed explicitly, a cursor is closed at the end of the compound statement in which it was declared.

17.2.10. Flow Control Constructs

The , , , , , and 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 statement might contain a loop, which itself contains a statement.

loops are not currently supported.

17.2.10.1.  Statement

IF  THEN 
    [ELSEIF  THEN ] ...
    [ELSE ]
END IF

implements a basic conditional construct. If the evaluates to true, the corresponding SQL statement list is executed. If no matches, the statement list in the clause is executed. Each consists of one or more statements.

Note: There is also an function, which differs from the statement described here. See Section 12.2, “Control Flow Functions”.

17.2.10.2.  Statement

CASE 
    WHEN  THEN 
    [WHEN  THEN ] ...
    [ELSE ]
END CASE

Or:

CASE
    WHEN  THEN 
    [WHEN  THEN ] ...
    [ELSE ]
END CASE

The statement for stored routines implements a complex conditional construct. If a evaluates to true, the corresponding SQL statement list is executed. If no search condition matches, the statement list in the clause is executed. Each consists of one or more statements.

Note: The syntax of the statement shown here for use inside stored routines differs slightly from that of the SQL expression described in Section 12.2, “Control Flow Functions”. The statement cannot have an clause, and it is terminated with instead of .

17.2.10.3.  Statement

[:] LOOP
    
END 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 statement.

A statement can be labeled. cannot be given unless also is present. If both are present, they must be the same.

17.2.10.4.  Statement

LEAVE 

This statement is used to exit any labeled flow control construct. It can be used within or loop constructs (, , ).

17.2.10.5.  Statement

ITERATE 

can appear only within , , and statements. 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

17.2.10.6.  Statement

[:] REPEAT
    
UNTIL 
END REPEAT []

The statement list within a statement is repeated until the is true. Thus, a always enters the loop at least once. consists of one or more statements.

A statement can be labeled. cannot be given unless also is present. If both are present, they must be the same.

Example:

mysql> 

mysql> 
    -> 
    ->   
    ->   
    -> 
    -> 
Query OK, 0 rows affected (0.00 sec)

mysql> 
Query OK, 0 rows affected (0.00 sec)

mysql> 
+------+
| @x   |
+------+
| 1001 |
+------+
1 row in set (0.00 sec)

17.2.10.7.  Statement

[:] WHILE  DO
    
END WHILE []

The statement list within a statement is repeated as long as the is true. consists of one or more statements.

A statement can be labeled. cannot be given unless 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