Skip to content

Commit

Permalink
MDEV-12007 Allow ROW variables as a cursor FETCH target
Browse files Browse the repository at this point in the history
  • Loading branch information
Alexander Barkov committed Apr 5, 2017
1 parent 72f43df commit d836f52
Show file tree
Hide file tree
Showing 7 changed files with 316 additions and 4 deletions.
106 changes: 106 additions & 0 deletions mysql-test/r/sp.result
Expand Up @@ -8127,3 +8127,109 @@ v_name v_total
c 1
DROP PROCEDURE p1;
DROP TABLE t1;
#
# Start of 10.3 tests
#
#
# MDEV-12007 Allow ROW variables as a cursor FETCH target
#
# The cursor and the ROW variable in FETCH must have the same number of fields
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT, bb VARCHAR(32), cc INT);
DECLARE cur CURSOR FOR SELECT 10 AS a,'b10' AS b;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
ERROR HY000: Incorrect number of FETCH variables
DROP PROCEDURE p1;
# Multiple ROW variables in FETCH
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec1 ROW(aa INT);
DECLARE rec2 ROW(aa INT);
DECLARE cur CURSOR FOR SELECT 10 AS a, 20 AS b;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec1, rec2;
IF done THEN
LEAVE read_loop;
END IF;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
ERROR 21000: Operand should contain 1 column(s)
DROP PROCEDURE p1;
# A complete working example
CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10,'b10');
INSERT INTO t1 VALUES (20,'b20');
INSERT INTO t1 VALUES (30,'b30');
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT, bb VARCHAR(32));
DECLARE cur CURSOR FOR SELECT a,b FROM t1;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
SELECT CONCAT('rec=(',rec.aa,',',rec.bb,')') AS c;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
c
rec=(10,b10)
c
rec=(20,b20)
c
rec=(30,b30)
DROP PROCEDURE p1;
DROP TABLE t1;
# A ROW variable with a single field
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT);
DECLARE cur CURSOR FOR SELECT 10 AS a UNION SELECT 20;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
SELECT CONCAT('rec=(',rec.aa,')') AS c;
END LOOP;
CLOSE cur;
END;
$$
CALL p1();
c
rec=(10)
c
rec=(20)
DROP PROCEDURE p1;
29 changes: 29 additions & 0 deletions mysql-test/suite/compat/oracle/r/sp-cursor.result
Expand Up @@ -783,3 +783,32 @@ a b c
DROP TABLE t2;
DROP PROCEDURE p1;
DROP TABLE t1;
#
# MDEV-12007 Allow ROW variables as a cursor FETCH target
#
CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10,'b10');
INSERT INTO t1 VALUES (20,'b20');
INSERT INTO t1 VALUES (30,'b30');
CREATE PROCEDURE p1 AS
rec ROW(a INT, b VARCHAR(32));
CURSOR c IS SELECT a,b FROM t1;
BEGIN
OPEN c;
LOOP
FETCH c INTO rec;
EXIT WHEN c%NOTFOUND;
SELECT ('rec=(' || rec.a ||','|| rec.b||')') AS c;
END LOOP;
CLOSE c;
END;
$$
CALL p1();
c
rec=(10,b10)
c
rec=(20,b20)
c
rec=(30,b30)
DROP PROCEDURE p1;
DROP TABLE t1;
27 changes: 27 additions & 0 deletions mysql-test/suite/compat/oracle/t/sp-cursor.test
Expand Up @@ -783,3 +783,30 @@ SELECT * FROM t2;
DROP TABLE t2;
DROP PROCEDURE p1;
DROP TABLE t1;

--echo #
--echo # MDEV-12007 Allow ROW variables as a cursor FETCH target
--echo #

CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10,'b10');
INSERT INTO t1 VALUES (20,'b20');
INSERT INTO t1 VALUES (30,'b30');
DELIMITER $$;
CREATE PROCEDURE p1 AS
rec ROW(a INT, b VARCHAR(32));
CURSOR c IS SELECT a,b FROM t1;
BEGIN
OPEN c;
LOOP
FETCH c INTO rec;
EXIT WHEN c%NOTFOUND;
SELECT ('rec=(' || rec.a ||','|| rec.b||')') AS c;
END LOOP;
CLOSE c;
END;
$$
DELIMITER ;$$
CALL p1();
DROP PROCEDURE p1;
DROP TABLE t1;
114 changes: 114 additions & 0 deletions mysql-test/t/sp.test
Expand Up @@ -9588,3 +9588,117 @@ DELIMITER ;|
CALL p1();
DROP PROCEDURE p1;
DROP TABLE t1;

--echo #
--echo # Start of 10.3 tests
--echo #

--echo #
--echo # MDEV-12007 Allow ROW variables as a cursor FETCH target
--echo #


--echo # The cursor and the ROW variable in FETCH must have the same number of fields
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT, bb VARCHAR(32), cc INT);
DECLARE cur CURSOR FOR SELECT 10 AS a,'b10' AS b;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
END LOOP;
CLOSE cur;
END;
$$
DELIMITER ;$$
--error ER_SP_WRONG_NO_OF_FETCH_ARGS
CALL p1();
DROP PROCEDURE p1;


--echo # Multiple ROW variables in FETCH
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec1 ROW(aa INT);
DECLARE rec2 ROW(aa INT);
DECLARE cur CURSOR FOR SELECT 10 AS a, 20 AS b;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec1, rec2;
IF done THEN
LEAVE read_loop;
END IF;
END LOOP;
CLOSE cur;
END;
$$
DELIMITER ;$$
--error ER_OPERAND_COLUMNS
CALL p1();
DROP PROCEDURE p1;


--echo # A complete working example
CREATE TABLE t1 (a INT, b VARCHAR(32));
INSERT INTO t1 VALUES (10,'b10');
INSERT INTO t1 VALUES (20,'b20');
INSERT INTO t1 VALUES (30,'b30');
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT, bb VARCHAR(32));
DECLARE cur CURSOR FOR SELECT a,b FROM t1;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
SELECT CONCAT('rec=(',rec.aa,',',rec.bb,')') AS c;
END LOOP;
CLOSE cur;
END;
$$
DELIMITER ;$$
CALL p1();
DROP PROCEDURE p1;
DROP TABLE t1;


--echo # A ROW variable with a single field
DELIMITER $$;
CREATE PROCEDURE p1()
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE rec ROW(aa INT);
DECLARE cur CURSOR FOR SELECT 10 AS a UNION SELECT 20;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN cur;
read_loop:
LOOP
FETCH cur INTO rec;
IF done THEN
LEAVE read_loop;
END IF;
SELECT CONCAT('rec=(',rec.aa,')') AS c;
END LOOP;
CLOSE cur;
END;
$$
DELIMITER ;$$
CALL p1();
DROP PROCEDURE p1;
6 changes: 6 additions & 0 deletions sql/field.h
Expand Up @@ -4037,6 +4037,12 @@ class Spvar_definition: public Column_definition
{
return m_row_field_definitions != NULL;
}
// Check if "this" defines a ROW variable with n elements
uint is_row(uint n) const
{
return m_row_field_definitions != NULL &&
m_row_field_definitions->elements == n;
}
Row_definition_list *row_field_definitions() const
{
return m_row_field_definitions;
Expand Down
36 changes: 32 additions & 4 deletions sql/sp_rcontext.cc
Expand Up @@ -572,6 +572,22 @@ int sp_rcontext::set_variable_row_field(THD *thd, uint var_idx, uint field_idx,
}


int sp_rcontext::set_variable_row(THD *thd, uint var_idx, List<Item> &items)
{
DBUG_ENTER("sp_rcontext::set_variable_row");
DBUG_ASSERT(thd->spcont->get_item(var_idx)->cols() == items.elements);
List_iterator<Item> it(items);
Item *item;
for (uint i= 0 ; (item= it++) ; i++)
{
int rc;
if ((rc= thd->spcont->set_variable_row_field(thd, var_idx, i, &item)))
DBUG_RETURN(rc);
}
DBUG_RETURN(0);
}


Item_cache *sp_rcontext::create_case_expr_holder(THD *thd,
const Item *item) const
{
Expand Down Expand Up @@ -688,7 +704,9 @@ int sp_cursor::fetch(THD *thd, List<sp_variable> *vars)
MYF(0));
return -1;
}
if (vars->elements != result.get_field_count())
if (vars->elements != result.get_field_count() &&
(vars->elements != 1 ||
!vars->head()->field_def.is_row(result.get_field_count())))
{
my_message(ER_SP_WRONG_NO_OF_FETCH_ARGS,
ER_THD(thd, ER_SP_WRONG_NO_OF_FETCH_ARGS), MYF(0));
Expand Down Expand Up @@ -743,15 +761,16 @@ int sp_cursor::Select_fetch_into_spvars::prepare(List<Item> &fields,
}


int sp_cursor::Select_fetch_into_spvars::send_data(List<Item> &items)
bool sp_cursor::Select_fetch_into_spvars::
send_data_to_variable_list(List<sp_variable> &vars, List<Item> &items)
{
List_iterator_fast<sp_variable> spvar_iter(*spvar_list);
List_iterator_fast<sp_variable> spvar_iter(vars);
List_iterator_fast<Item> item_iter(items);
sp_variable *spvar;
Item *item;

/* Must be ensured by the caller */
DBUG_ASSERT(spvar_list->elements == items.elements);
DBUG_ASSERT(vars.elements == items.elements);

/*
Assign the row fetched from a server side cursor to stored
Expand All @@ -764,3 +783,12 @@ int sp_cursor::Select_fetch_into_spvars::send_data(List<Item> &items)
}
return false;
}


int sp_cursor::Select_fetch_into_spvars::send_data(List<Item> &items)
{
return (spvar_list->elements == 1 &&
(spvar_list->head())->field_def.is_row(items.elements)) ?
thd->spcont->set_variable_row(thd, spvar_list->head()->offset, items) :
send_data_to_variable_list(*spvar_list, items);
}
2 changes: 2 additions & 0 deletions sql/sp_rcontext.h
Expand Up @@ -190,6 +190,7 @@ class sp_rcontext : public Sql_alloc
void set_variable_row_field_to_null(THD *thd, uint var_idx, uint field_idx);
int set_variable_row_field(THD *thd, uint var_idx, uint field_idx,
Item **value);
int set_variable_row(THD *thd, uint var_idx, List<Item> &items);
Item *get_item(uint var_idx) const
{ return m_var_items[var_idx]; }

Expand Down Expand Up @@ -419,6 +420,7 @@ class sp_cursor : public Sql_alloc
{
List<sp_variable> *spvar_list;
uint field_count;
bool send_data_to_variable_list(List<sp_variable> &vars, List<Item> &items);
public:
Select_fetch_into_spvars(THD *thd_arg): select_result_interceptor(thd_arg) {}
uint get_field_count() { return field_count; }
Expand Down

0 comments on commit d836f52

Please sign in to comment.