MySQL 8.4 Reference Manual Including MySQL NDB Cluster 8.4
The scope of a local variable is the
BEGIN ...
END
block within which 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.
Because local variables are in scope only during stored program
execution, references to them are not permitted in prepared
statements created within a stored program. Prepared statement
scope is the current session, not the stored program, so the
statement could be executed after the program ends, at which
point the variables would no longer be in scope. For example,
SELECT ... INTO
cannot be used as
a prepared statement. This restriction also applies to stored
procedure and function parameters. See
Section 15.5.1, “PREPARE Statement”.
local_var
A local variable should not have the same name as a table
column. 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. Consider the
following procedure definition:
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;
MySQL interprets xname
in the
SELECT
statement as a reference
to the xname
variable
rather than the xname
column. Consequently, when the procedure
sp1()
is called, the
newname
variable returns the value
'bob'
regardless of the value of the
table1.xname
column.
Similarly, the cursor definition in the following procedure
contains a SELECT
statement that
refers to xname
. MySQL interprets this as a
reference to the variable of that name rather than a column
reference.
CREATE PROCEDURE sp2 (x VARCHAR(5)) BEGIN DECLARE xname VARCHAR(5) DEFAULT 'bob'; DECLARE newname VARCHAR(5); DECLARE xid INT; DECLARE done TINYINT DEFAULT 0; DECLARE cur1 CURSOR FOR SELECT xname, id FROM table1; DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1; OPEN cur1; read_loop: LOOP FETCH FROM cur1 INTO newname, xid; IF done THEN LEAVE read_loop; END IF; SELECT newname; END LOOP; CLOSE cur1; END;