Skip to content

Commit d836f52

Browse files
author
Alexander Barkov
committed
MDEV-12007 Allow ROW variables as a cursor FETCH target
1 parent 72f43df commit d836f52

File tree

7 files changed

+316
-4
lines changed

7 files changed

+316
-4
lines changed

mysql-test/r/sp.result

Lines changed: 106 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -8127,3 +8127,109 @@ v_name v_total
81278127
c 1
81288128
DROP PROCEDURE p1;
81298129
DROP TABLE t1;
8130+
#
8131+
# Start of 10.3 tests
8132+
#
8133+
#
8134+
# MDEV-12007 Allow ROW variables as a cursor FETCH target
8135+
#
8136+
# The cursor and the ROW variable in FETCH must have the same number of fields
8137+
CREATE PROCEDURE p1()
8138+
BEGIN
8139+
DECLARE done INT DEFAULT FALSE;
8140+
DECLARE rec ROW(aa INT, bb VARCHAR(32), cc INT);
8141+
DECLARE cur CURSOR FOR SELECT 10 AS a,'b10' AS b;
8142+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
8143+
OPEN cur;
8144+
read_loop:
8145+
LOOP
8146+
FETCH cur INTO rec;
8147+
IF done THEN
8148+
LEAVE read_loop;
8149+
END IF;
8150+
END LOOP;
8151+
CLOSE cur;
8152+
END;
8153+
$$
8154+
CALL p1();
8155+
ERROR HY000: Incorrect number of FETCH variables
8156+
DROP PROCEDURE p1;
8157+
# Multiple ROW variables in FETCH
8158+
CREATE PROCEDURE p1()
8159+
BEGIN
8160+
DECLARE done INT DEFAULT FALSE;
8161+
DECLARE rec1 ROW(aa INT);
8162+
DECLARE rec2 ROW(aa INT);
8163+
DECLARE cur CURSOR FOR SELECT 10 AS a, 20 AS b;
8164+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
8165+
OPEN cur;
8166+
read_loop:
8167+
LOOP
8168+
FETCH cur INTO rec1, rec2;
8169+
IF done THEN
8170+
LEAVE read_loop;
8171+
END IF;
8172+
END LOOP;
8173+
CLOSE cur;
8174+
END;
8175+
$$
8176+
CALL p1();
8177+
ERROR 21000: Operand should contain 1 column(s)
8178+
DROP PROCEDURE p1;
8179+
# A complete working example
8180+
CREATE TABLE t1 (a INT, b VARCHAR(32));
8181+
INSERT INTO t1 VALUES (10,'b10');
8182+
INSERT INTO t1 VALUES (20,'b20');
8183+
INSERT INTO t1 VALUES (30,'b30');
8184+
CREATE PROCEDURE p1()
8185+
BEGIN
8186+
DECLARE done INT DEFAULT FALSE;
8187+
DECLARE rec ROW(aa INT, bb VARCHAR(32));
8188+
DECLARE cur CURSOR FOR SELECT a,b FROM t1;
8189+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
8190+
OPEN cur;
8191+
read_loop:
8192+
LOOP
8193+
FETCH cur INTO rec;
8194+
IF done THEN
8195+
LEAVE read_loop;
8196+
END IF;
8197+
SELECT CONCAT('rec=(',rec.aa,',',rec.bb,')') AS c;
8198+
END LOOP;
8199+
CLOSE cur;
8200+
END;
8201+
$$
8202+
CALL p1();
8203+
c
8204+
rec=(10,b10)
8205+
c
8206+
rec=(20,b20)
8207+
c
8208+
rec=(30,b30)
8209+
DROP PROCEDURE p1;
8210+
DROP TABLE t1;
8211+
# A ROW variable with a single field
8212+
CREATE PROCEDURE p1()
8213+
BEGIN
8214+
DECLARE done INT DEFAULT FALSE;
8215+
DECLARE rec ROW(aa INT);
8216+
DECLARE cur CURSOR FOR SELECT 10 AS a UNION SELECT 20;
8217+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
8218+
OPEN cur;
8219+
read_loop:
8220+
LOOP
8221+
FETCH cur INTO rec;
8222+
IF done THEN
8223+
LEAVE read_loop;
8224+
END IF;
8225+
SELECT CONCAT('rec=(',rec.aa,')') AS c;
8226+
END LOOP;
8227+
CLOSE cur;
8228+
END;
8229+
$$
8230+
CALL p1();
8231+
c
8232+
rec=(10)
8233+
c
8234+
rec=(20)
8235+
DROP PROCEDURE p1;

mysql-test/suite/compat/oracle/r/sp-cursor.result

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -783,3 +783,32 @@ a b c
783783
DROP TABLE t2;
784784
DROP PROCEDURE p1;
785785
DROP TABLE t1;
786+
#
787+
# MDEV-12007 Allow ROW variables as a cursor FETCH target
788+
#
789+
CREATE TABLE t1 (a INT, b VARCHAR(32));
790+
INSERT INTO t1 VALUES (10,'b10');
791+
INSERT INTO t1 VALUES (20,'b20');
792+
INSERT INTO t1 VALUES (30,'b30');
793+
CREATE PROCEDURE p1 AS
794+
rec ROW(a INT, b VARCHAR(32));
795+
CURSOR c IS SELECT a,b FROM t1;
796+
BEGIN
797+
OPEN c;
798+
LOOP
799+
FETCH c INTO rec;
800+
EXIT WHEN c%NOTFOUND;
801+
SELECT ('rec=(' || rec.a ||','|| rec.b||')') AS c;
802+
END LOOP;
803+
CLOSE c;
804+
END;
805+
$$
806+
CALL p1();
807+
c
808+
rec=(10,b10)
809+
c
810+
rec=(20,b20)
811+
c
812+
rec=(30,b30)
813+
DROP PROCEDURE p1;
814+
DROP TABLE t1;

mysql-test/suite/compat/oracle/t/sp-cursor.test

Lines changed: 27 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -783,3 +783,30 @@ SELECT * FROM t2;
783783
DROP TABLE t2;
784784
DROP PROCEDURE p1;
785785
DROP TABLE t1;
786+
787+
--echo #
788+
--echo # MDEV-12007 Allow ROW variables as a cursor FETCH target
789+
--echo #
790+
791+
CREATE TABLE t1 (a INT, b VARCHAR(32));
792+
INSERT INTO t1 VALUES (10,'b10');
793+
INSERT INTO t1 VALUES (20,'b20');
794+
INSERT INTO t1 VALUES (30,'b30');
795+
DELIMITER $$;
796+
CREATE PROCEDURE p1 AS
797+
rec ROW(a INT, b VARCHAR(32));
798+
CURSOR c IS SELECT a,b FROM t1;
799+
BEGIN
800+
OPEN c;
801+
LOOP
802+
FETCH c INTO rec;
803+
EXIT WHEN c%NOTFOUND;
804+
SELECT ('rec=(' || rec.a ||','|| rec.b||')') AS c;
805+
END LOOP;
806+
CLOSE c;
807+
END;
808+
$$
809+
DELIMITER ;$$
810+
CALL p1();
811+
DROP PROCEDURE p1;
812+
DROP TABLE t1;

mysql-test/t/sp.test

Lines changed: 114 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -9588,3 +9588,117 @@ DELIMITER ;|
95889588
CALL p1();
95899589
DROP PROCEDURE p1;
95909590
DROP TABLE t1;
9591+
9592+
--echo #
9593+
--echo # Start of 10.3 tests
9594+
--echo #
9595+
9596+
--echo #
9597+
--echo # MDEV-12007 Allow ROW variables as a cursor FETCH target
9598+
--echo #
9599+
9600+
9601+
--echo # The cursor and the ROW variable in FETCH must have the same number of fields
9602+
DELIMITER $$;
9603+
CREATE PROCEDURE p1()
9604+
BEGIN
9605+
DECLARE done INT DEFAULT FALSE;
9606+
DECLARE rec ROW(aa INT, bb VARCHAR(32), cc INT);
9607+
DECLARE cur CURSOR FOR SELECT 10 AS a,'b10' AS b;
9608+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
9609+
OPEN cur;
9610+
read_loop:
9611+
LOOP
9612+
FETCH cur INTO rec;
9613+
IF done THEN
9614+
LEAVE read_loop;
9615+
END IF;
9616+
END LOOP;
9617+
CLOSE cur;
9618+
END;
9619+
$$
9620+
DELIMITER ;$$
9621+
--error ER_SP_WRONG_NO_OF_FETCH_ARGS
9622+
CALL p1();
9623+
DROP PROCEDURE p1;
9624+
9625+
9626+
--echo # Multiple ROW variables in FETCH
9627+
DELIMITER $$;
9628+
CREATE PROCEDURE p1()
9629+
BEGIN
9630+
DECLARE done INT DEFAULT FALSE;
9631+
DECLARE rec1 ROW(aa INT);
9632+
DECLARE rec2 ROW(aa INT);
9633+
DECLARE cur CURSOR FOR SELECT 10 AS a, 20 AS b;
9634+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
9635+
OPEN cur;
9636+
read_loop:
9637+
LOOP
9638+
FETCH cur INTO rec1, rec2;
9639+
IF done THEN
9640+
LEAVE read_loop;
9641+
END IF;
9642+
END LOOP;
9643+
CLOSE cur;
9644+
END;
9645+
$$
9646+
DELIMITER ;$$
9647+
--error ER_OPERAND_COLUMNS
9648+
CALL p1();
9649+
DROP PROCEDURE p1;
9650+
9651+
9652+
--echo # A complete working example
9653+
CREATE TABLE t1 (a INT, b VARCHAR(32));
9654+
INSERT INTO t1 VALUES (10,'b10');
9655+
INSERT INTO t1 VALUES (20,'b20');
9656+
INSERT INTO t1 VALUES (30,'b30');
9657+
DELIMITER $$;
9658+
CREATE PROCEDURE p1()
9659+
BEGIN
9660+
DECLARE done INT DEFAULT FALSE;
9661+
DECLARE rec ROW(aa INT, bb VARCHAR(32));
9662+
DECLARE cur CURSOR FOR SELECT a,b FROM t1;
9663+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
9664+
OPEN cur;
9665+
read_loop:
9666+
LOOP
9667+
FETCH cur INTO rec;
9668+
IF done THEN
9669+
LEAVE read_loop;
9670+
END IF;
9671+
SELECT CONCAT('rec=(',rec.aa,',',rec.bb,')') AS c;
9672+
END LOOP;
9673+
CLOSE cur;
9674+
END;
9675+
$$
9676+
DELIMITER ;$$
9677+
CALL p1();
9678+
DROP PROCEDURE p1;
9679+
DROP TABLE t1;
9680+
9681+
9682+
--echo # A ROW variable with a single field
9683+
DELIMITER $$;
9684+
CREATE PROCEDURE p1()
9685+
BEGIN
9686+
DECLARE done INT DEFAULT FALSE;
9687+
DECLARE rec ROW(aa INT);
9688+
DECLARE cur CURSOR FOR SELECT 10 AS a UNION SELECT 20;
9689+
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
9690+
OPEN cur;
9691+
read_loop:
9692+
LOOP
9693+
FETCH cur INTO rec;
9694+
IF done THEN
9695+
LEAVE read_loop;
9696+
END IF;
9697+
SELECT CONCAT('rec=(',rec.aa,')') AS c;
9698+
END LOOP;
9699+
CLOSE cur;
9700+
END;
9701+
$$
9702+
DELIMITER ;$$
9703+
CALL p1();
9704+
DROP PROCEDURE p1;

sql/field.h

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4037,6 +4037,12 @@ class Spvar_definition: public Column_definition
40374037
{
40384038
return m_row_field_definitions != NULL;
40394039
}
4040+
// Check if "this" defines a ROW variable with n elements
4041+
uint is_row(uint n) const
4042+
{
4043+
return m_row_field_definitions != NULL &&
4044+
m_row_field_definitions->elements == n;
4045+
}
40404046
Row_definition_list *row_field_definitions() const
40414047
{
40424048
return m_row_field_definitions;

sql/sp_rcontext.cc

Lines changed: 32 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -572,6 +572,22 @@ int sp_rcontext::set_variable_row_field(THD *thd, uint var_idx, uint field_idx,
572572
}
573573

574574

575+
int sp_rcontext::set_variable_row(THD *thd, uint var_idx, List<Item> &items)
576+
{
577+
DBUG_ENTER("sp_rcontext::set_variable_row");
578+
DBUG_ASSERT(thd->spcont->get_item(var_idx)->cols() == items.elements);
579+
List_iterator<Item> it(items);
580+
Item *item;
581+
for (uint i= 0 ; (item= it++) ; i++)
582+
{
583+
int rc;
584+
if ((rc= thd->spcont->set_variable_row_field(thd, var_idx, i, &item)))
585+
DBUG_RETURN(rc);
586+
}
587+
DBUG_RETURN(0);
588+
}
589+
590+
575591
Item_cache *sp_rcontext::create_case_expr_holder(THD *thd,
576592
const Item *item) const
577593
{
@@ -688,7 +704,9 @@ int sp_cursor::fetch(THD *thd, List<sp_variable> *vars)
688704
MYF(0));
689705
return -1;
690706
}
691-
if (vars->elements != result.get_field_count())
707+
if (vars->elements != result.get_field_count() &&
708+
(vars->elements != 1 ||
709+
!vars->head()->field_def.is_row(result.get_field_count())))
692710
{
693711
my_message(ER_SP_WRONG_NO_OF_FETCH_ARGS,
694712
ER_THD(thd, ER_SP_WRONG_NO_OF_FETCH_ARGS), MYF(0));
@@ -743,15 +761,16 @@ int sp_cursor::Select_fetch_into_spvars::prepare(List<Item> &fields,
743761
}
744762

745763

746-
int sp_cursor::Select_fetch_into_spvars::send_data(List<Item> &items)
764+
bool sp_cursor::Select_fetch_into_spvars::
765+
send_data_to_variable_list(List<sp_variable> &vars, List<Item> &items)
747766
{
748-
List_iterator_fast<sp_variable> spvar_iter(*spvar_list);
767+
List_iterator_fast<sp_variable> spvar_iter(vars);
749768
List_iterator_fast<Item> item_iter(items);
750769
sp_variable *spvar;
751770
Item *item;
752771

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

756775
/*
757776
Assign the row fetched from a server side cursor to stored
@@ -764,3 +783,12 @@ int sp_cursor::Select_fetch_into_spvars::send_data(List<Item> &items)
764783
}
765784
return false;
766785
}
786+
787+
788+
int sp_cursor::Select_fetch_into_spvars::send_data(List<Item> &items)
789+
{
790+
return (spvar_list->elements == 1 &&
791+
(spvar_list->head())->field_def.is_row(items.elements)) ?
792+
thd->spcont->set_variable_row(thd, spvar_list->head()->offset, items) :
793+
send_data_to_variable_list(*spvar_list, items);
794+
}

sql/sp_rcontext.h

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -190,6 +190,7 @@ class sp_rcontext : public Sql_alloc
190190
void set_variable_row_field_to_null(THD *thd, uint var_idx, uint field_idx);
191191
int set_variable_row_field(THD *thd, uint var_idx, uint field_idx,
192192
Item **value);
193+
int set_variable_row(THD *thd, uint var_idx, List<Item> &items);
193194
Item *get_item(uint var_idx) const
194195
{ return m_var_items[var_idx]; }
195196

@@ -419,6 +420,7 @@ class sp_cursor : public Sql_alloc
419420
{
420421
List<sp_variable> *spvar_list;
421422
uint field_count;
423+
bool send_data_to_variable_list(List<sp_variable> &vars, List<Item> &items);
422424
public:
423425
Select_fetch_into_spvars(THD *thd_arg): select_result_interceptor(thd_arg) {}
424426
uint get_field_count() { return field_count; }

0 commit comments

Comments
 (0)