From e0451941ccb6adc11490099cdb7b1564af62ee68 Mon Sep 17 00:00:00 2001
From: Alexander Barkov <bar@mariadb.org>
Date: Sat, 18 Mar 2017 17:39:17 +0400
Subject: [PATCH] MDEV-12291 Allow ROW variables as SELECT INTO targets

---
 mysql-test/r/sp-row.result                    |  46 +++++
 .../binlog/r/binlog_stm_sp_type_row.result    |  48 +++++
 .../binlog/t/binlog_stm_sp_type_row.test      |  27 +++
 .../compat/oracle/r/binlog_stm_sp.result      | 143 +++++++++++++++
 .../suite/compat/oracle/r/sp-row.result       | 135 ++++++++++++++
 .../suite/compat/oracle/t/binlog_stm_sp.test  |  74 ++++++++
 mysql-test/suite/compat/oracle/t/sp-row.test  | 167 ++++++++++++++++++
 mysql-test/t/sp-row.test                      |  58 ++++++
 sql/field.h                                   |   6 +
 sql/sp_pcontext.h                             |   3 +
 sql/sql_class.cc                              |  53 ++++--
 sql/sql_class.h                               |  19 +-
 sql/sql_yacc.yy                               |   2 +-
 sql/sql_yacc_ora.yy                           |   2 +-
 14 files changed, 762 insertions(+), 21 deletions(-)

diff --git a/mysql-test/r/sp-row.result b/mysql-test/r/sp-row.result
index 8c4973ba46c..687e6629b8d 100644
--- a/mysql-test/r/sp-row.result
+++ b/mysql-test/r/sp-row.result
@@ -2120,3 +2120,49 @@ DROP PROCEDURE p1;
 #
 # End of MDEV-10914 ROW data type for stored routine variables
 #
+#
+# MDEV-12291 Allow ROW variables as SELECT INTO targets
+#
+# ROW variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1()
+BEGIN
+DECLARE rec1 ROW(a INT, b VARCHAR(32), c DOUBLE);
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: The used SELECT statements have a different number of columns
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# Multiple ROW variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1()
+BEGIN
+DECLARE rec1 ROW(a INT, b VARCHAR(32));
+SELECT * FROM t1 INTO rec1, rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: Operand should contain 2 column(s)
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# ROW variables working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1()
+BEGIN
+DECLARE rec1 ROW(a INT, b VARCHAR(32));
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+rec1.a	rec1.b
+10	b10
+DROP TABLE t1;
+DROP PROCEDURE p1;
diff --git a/mysql-test/suite/binlog/r/binlog_stm_sp_type_row.result b/mysql-test/suite/binlog/r/binlog_stm_sp_type_row.result
index 55d0dc13e56..cc21904f5af 100644
--- a/mysql-test/suite/binlog/r/binlog_stm_sp_type_row.result
+++ b/mysql-test/suite/binlog/r/binlog_stm_sp_type_row.result
@@ -177,3 +177,51 @@ master-bin.000002	#	Query	#	#	use `test`; DROP PROCEDURE p1
 #
 # End of MDEV-10914 ROW data type for stored routine variables
 #
+#
+# MDEV-12291 Allow ROW variables as SELECT INTO targets
+#
+FLUSH LOGS;
+SET sql_mode=DEFAULT;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+CREATE PROCEDURE p1()
+BEGIN
+DECLARE rec1 ROW(a INT, b VARCHAR(32));
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+CALL p1();
+SELECT * FROM t1;
+a	b
+10	b10
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+include/show_binlog_events.inc
+Log_name	Pos	Event_type	Server_id	End_log_pos	Info
+master-bin.000003	#	Binlog_checkpoint	#	#	master-bin.000003
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; CREATE TABLE t1 (a INT, b VARCHAR(32))
+master-bin.000003	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; INSERT INTO t1 VALUES (10, 'b10')
+master-bin.000003	#	Query	#	#	COMMIT
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; CREATE TABLE t2 LIKE t1
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; CREATE DEFINER=`root`@`localhost` PROCEDURE `p1`()
+BEGIN
+DECLARE rec1 ROW(a INT, b VARCHAR(32));
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END
+master-bin.000003	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; INSERT INTO t2 VALUES ( NAME_CONST('rec1.a',10),  NAME_CONST('rec1.b',_latin1'b10' COLLATE 'latin1_swedish_ci'))
+master-bin.000003	#	Query	#	#	COMMIT
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; DROP TABLE `t1` /* generated by server */
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; DROP TABLE `t2` /* generated by server */
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; DROP PROCEDURE p1
diff --git a/mysql-test/suite/binlog/t/binlog_stm_sp_type_row.test b/mysql-test/suite/binlog/t/binlog_stm_sp_type_row.test
index cd0d9111107..a7e21ee55c5 100644
--- a/mysql-test/suite/binlog/t/binlog_stm_sp_type_row.test
+++ b/mysql-test/suite/binlog/t/binlog_stm_sp_type_row.test
@@ -79,3 +79,30 @@ source include/show_binlog_events.inc;
 --echo #
 --echo # End of MDEV-10914 ROW data type for stored routine variables
 --echo #
+
+
+--echo #
+--echo # MDEV-12291 Allow ROW variables as SELECT INTO targets
+--echo #
+
+FLUSH LOGS;
+SET sql_mode=DEFAULT;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+DELIMITER $$;
+CREATE PROCEDURE p1()
+BEGIN
+  DECLARE rec1 ROW(a INT, b VARCHAR(32));
+  SELECT * INTO rec1 FROM t1;
+  INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+SELECT * FROM t1;
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+--let $binlog_file = LAST
+source include/show_binlog_events.inc;
diff --git a/mysql-test/suite/compat/oracle/r/binlog_stm_sp.result b/mysql-test/suite/compat/oracle/r/binlog_stm_sp.result
index a927157356a..d6aa6cd4ace 100644
--- a/mysql-test/suite/compat/oracle/r/binlog_stm_sp.result
+++ b/mysql-test/suite/compat/oracle/r/binlog_stm_sp.result
@@ -328,3 +328,146 @@ master-bin.000002	#	Gtid	#	#	GTID #-#-#
 master-bin.000002	#	Query	#	#	use `test`; DROP TABLE "t1" /* generated by server */
 master-bin.000002	#	Gtid	#	#	GTID #-#-#
 master-bin.000002	#	Query	#	#	use `test`; DROP PROCEDURE p1
+#
+# MDEV-12291 Allow ROW variables as SELECT INTO targets
+#
+FLUSH LOGS;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+CREATE PROCEDURE p1
+AS
+rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+CALL p1();
+SELECT * FROM t1;
+a	b
+10	b10
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+include/show_binlog_events.inc
+Log_name	Pos	Event_type	Server_id	End_log_pos	Info
+master-bin.000003	#	Binlog_checkpoint	#	#	master-bin.000003
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; CREATE TABLE t1 (a INT, b VARCHAR(32))
+master-bin.000003	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; INSERT INTO t1 VALUES (10, 'b10')
+master-bin.000003	#	Query	#	#	COMMIT
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; CREATE TABLE t2 LIKE t1
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
+AS
+rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END
+master-bin.000003	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; INSERT INTO t2 VALUES ( NAME_CONST('rec1.a',10),  NAME_CONST('rec1.b',_latin1'b10' COLLATE 'latin1_swedish_ci'))
+master-bin.000003	#	Query	#	#	COMMIT
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; DROP TABLE "t1" /* generated by server */
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; DROP TABLE "t2" /* generated by server */
+master-bin.000003	#	Gtid	#	#	GTID #-#-#
+master-bin.000003	#	Query	#	#	use `test`; DROP PROCEDURE p1
+FLUSH LOGS;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+CREATE PROCEDURE p1
+AS
+rec1 t1%ROWTYPE;
+BEGIN
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+CALL p1();
+SELECT * FROM t1;
+a	b
+10	b10
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+include/show_binlog_events.inc
+Log_name	Pos	Event_type	Server_id	End_log_pos	Info
+master-bin.000004	#	Binlog_checkpoint	#	#	master-bin.000004
+master-bin.000004	#	Gtid	#	#	GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; CREATE TABLE t1 (a INT, b VARCHAR(32))
+master-bin.000004	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; INSERT INTO t1 VALUES (10, 'b10')
+master-bin.000004	#	Query	#	#	COMMIT
+master-bin.000004	#	Gtid	#	#	GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; CREATE TABLE t2 LIKE t1
+master-bin.000004	#	Gtid	#	#	GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
+AS
+rec1 t1%ROWTYPE;
+BEGIN
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END
+master-bin.000004	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; INSERT INTO t2 VALUES ( NAME_CONST('rec1.a',10),  NAME_CONST('rec1.b',_latin1'b10' COLLATE 'latin1_swedish_ci'))
+master-bin.000004	#	Query	#	#	COMMIT
+master-bin.000004	#	Gtid	#	#	GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; DROP TABLE "t1" /* generated by server */
+master-bin.000004	#	Gtid	#	#	GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; DROP TABLE "t2" /* generated by server */
+master-bin.000004	#	Gtid	#	#	GTID #-#-#
+master-bin.000004	#	Query	#	#	use `test`; DROP PROCEDURE p1
+FLUSH LOGS;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+CREATE PROCEDURE p1
+AS
+CURSOR cur1 IS SELECT * FROM t1;
+rec1 cur1%ROWTYPE;
+BEGIN
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+CALL p1();
+SELECT * FROM t1;
+a	b
+10	b10
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+include/show_binlog_events.inc
+Log_name	Pos	Event_type	Server_id	End_log_pos	Info
+master-bin.000005	#	Binlog_checkpoint	#	#	master-bin.000005
+master-bin.000005	#	Gtid	#	#	GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; CREATE TABLE t1 (a INT, b VARCHAR(32))
+master-bin.000005	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; INSERT INTO t1 VALUES (10, 'b10')
+master-bin.000005	#	Query	#	#	COMMIT
+master-bin.000005	#	Gtid	#	#	GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; CREATE TABLE t2 LIKE t1
+master-bin.000005	#	Gtid	#	#	GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; CREATE DEFINER="root"@"localhost" PROCEDURE "p1"()
+AS
+CURSOR cur1 IS SELECT * FROM t1;
+rec1 cur1%ROWTYPE;
+BEGIN
+SELECT * INTO rec1 FROM t1;
+INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END
+master-bin.000005	#	Gtid	#	#	BEGIN GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; INSERT INTO t2 VALUES ( NAME_CONST('rec1.a',10),  NAME_CONST('rec1.b',_latin1'b10' COLLATE 'latin1_swedish_ci'))
+master-bin.000005	#	Query	#	#	COMMIT
+master-bin.000005	#	Gtid	#	#	GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; DROP TABLE "t1" /* generated by server */
+master-bin.000005	#	Gtid	#	#	GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; DROP TABLE "t2" /* generated by server */
+master-bin.000005	#	Gtid	#	#	GTID #-#-#
+master-bin.000005	#	Query	#	#	use `test`; DROP PROCEDURE p1
diff --git a/mysql-test/suite/compat/oracle/r/sp-row.result b/mysql-test/suite/compat/oracle/r/sp-row.result
index 4846f6ccf0a..5c9275733a9 100644
--- a/mysql-test/suite/compat/oracle/r/sp-row.result
+++ b/mysql-test/suite/compat/oracle/r/sp-row.result
@@ -2819,3 +2819,138 @@ CALL p1();
 ERROR HY000: Row variable 'rec' does not have a field 'c'
 DROP TABLE t1;
 DROP PROCEDURE p1;
+#
+# MDEV-12291 Allow ROW variables as SELECT INTO targets
+#
+# ROW variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+rec1 ROW(a INT, b VARCHAR(32), c DOUBLE);
+BEGIN
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: The used SELECT statements have a different number of columns
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# Multiple ROW variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+SELECT * FROM t1 INTO rec1, rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: Operand should contain 2 column(s)
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# ROW variables working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+rec1.a	rec1.b
+10	b10
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# table%ROWTYPE variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+rec1 t1%ROWTYPE;
+BEGIN
+SELECT 10,'a','b' FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: The used SELECT statements have a different number of columns
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# Multiple table%ROWTYPE variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+rec1 t1%ROWTYPE;
+BEGIN
+SELECT 10,'a' FROM t1 INTO rec1, rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: Operand should contain 2 column(s)
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# table%ROWTYPE working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+rec1 t1%ROWTYPE;
+BEGIN
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+rec1.a	rec1.b
+10	b10
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# cursor%ROWTYPE variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+CURSOR cur1 IS SELECT 10, 'b0', 'c0';
+rec1 cur1%ROWTYPE;
+BEGIN
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: The used SELECT statements have a different number of columns
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# Multiple cursor%ROWTYPE variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+CURSOR cur1 IS SELECT * FROM t1;
+rec1 cur1%ROWTYPE;
+BEGIN
+SELECT * FROM t1 INTO rec1, rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+ERROR 21000: Operand should contain 2 column(s)
+DROP TABLE t1;
+DROP PROCEDURE p1;
+# cursor%ROWTYPE working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+CREATE PROCEDURE p1 AS
+CURSOR cur1 IS SELECT * FROM t1;
+rec1 cur1%ROWTYPE;
+BEGIN
+SELECT * FROM t1 INTO rec1;
+SELECT rec1.a, rec1.b;
+END;
+$$
+CALL p1();
+rec1.a	rec1.b
+10	b10
+DROP TABLE t1;
+DROP PROCEDURE p1;
diff --git a/mysql-test/suite/compat/oracle/t/binlog_stm_sp.test b/mysql-test/suite/compat/oracle/t/binlog_stm_sp.test
index ee4c5c8065a..813b905477e 100644
--- a/mysql-test/suite/compat/oracle/t/binlog_stm_sp.test
+++ b/mysql-test/suite/compat/oracle/t/binlog_stm_sp.test
@@ -119,3 +119,77 @@ DROP TABLE t1;
 DROP PROCEDURE p1;
 --let $binlog_file = LAST
 source include/show_binlog_events.inc;
+
+
+--echo #
+--echo # MDEV-12291 Allow ROW variables as SELECT INTO targets
+--echo #
+
+FLUSH LOGS;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+DELIMITER $$;
+CREATE PROCEDURE p1
+AS
+  rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+  SELECT * INTO rec1 FROM t1;
+  INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+SELECT * FROM t1;
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+--let $binlog_file = LAST
+source include/show_binlog_events.inc;
+
+
+FLUSH LOGS;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+DELIMITER $$;
+CREATE PROCEDURE p1
+AS
+  rec1 t1%ROWTYPE;
+BEGIN
+  SELECT * INTO rec1 FROM t1;
+  INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+SELECT * FROM t1;
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+--let $binlog_file = LAST
+source include/show_binlog_events.inc;
+
+
+FLUSH LOGS;
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10, 'b10');
+CREATE TABLE t2 LIKE t1;
+DELIMITER $$;
+CREATE PROCEDURE p1
+AS
+  CURSOR cur1 IS SELECT * FROM t1;
+  rec1 cur1%ROWTYPE;
+BEGIN
+  SELECT * INTO rec1 FROM t1;
+  INSERT INTO t2 VALUES (rec1.a, rec1.b);
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+SELECT * FROM t1;
+DROP TABLE t1;
+DROP TABLE t2;
+DROP PROCEDURE p1;
+--let $binlog_file = LAST
+source include/show_binlog_events.inc;
diff --git a/mysql-test/suite/compat/oracle/t/sp-row.test b/mysql-test/suite/compat/oracle/t/sp-row.test
index d499cf2591f..8ae956b464d 100644
--- a/mysql-test/suite/compat/oracle/t/sp-row.test
+++ b/mysql-test/suite/compat/oracle/t/sp-row.test
@@ -2075,3 +2075,170 @@ DELIMITER ;$$
 CALL p1();
 DROP TABLE t1;
 DROP PROCEDURE p1;
+
+
+--echo #
+--echo # MDEV-12291 Allow ROW variables as SELECT INTO targets
+--echo #
+
+
+--echo # ROW variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  rec1 ROW(a INT, b VARCHAR(32), c DOUBLE);
+BEGIN
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # Multiple ROW variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+  SELECT * FROM t1 INTO rec1, rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_OPERAND_COLUMNS
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # ROW variables working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  rec1 ROW(a INT, b VARCHAR(32));
+BEGIN
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # table%ROWTYPE variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  rec1 t1%ROWTYPE;
+BEGIN
+  SELECT 10,'a','b' FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # Multiple table%ROWTYPE variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  rec1 t1%ROWTYPE;
+BEGIN
+  SELECT 10,'a' FROM t1 INTO rec1, rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_OPERAND_COLUMNS
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # table%ROWTYPE working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  rec1 t1%ROWTYPE;
+BEGIN
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # cursor%ROWTYPE variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  CURSOR cur1 IS SELECT 10, 'b0', 'c0';
+  rec1 cur1%ROWTYPE;
+BEGIN
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # Multiple cursor%ROWTYPE variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  CURSOR cur1 IS SELECT * FROM t1;
+  rec1 cur1%ROWTYPE;
+BEGIN
+  SELECT * FROM t1 INTO rec1, rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_OPERAND_COLUMNS
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # cursor%ROWTYPE working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1 AS
+  CURSOR cur1 IS SELECT * FROM t1;
+  rec1 cur1%ROWTYPE;
+BEGIN
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
diff --git a/mysql-test/t/sp-row.test b/mysql-test/t/sp-row.test
index cf1f99468be..e9e141b2533 100644
--- a/mysql-test/t/sp-row.test
+++ b/mysql-test/t/sp-row.test
@@ -1327,3 +1327,61 @@ DROP PROCEDURE p1;
 --echo #
 --echo # End of MDEV-10914 ROW data type for stored routine variables
 --echo #
+
+
+--echo #
+--echo # MDEV-12291 Allow ROW variables as SELECT INTO targets
+--echo #
+
+
+--echo # ROW variable with a wrong column count
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1()
+BEGIN
+  DECLARE rec1 ROW(a INT, b VARCHAR(32), c DOUBLE);
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # Multiple ROW variables
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1()
+BEGIN
+  DECLARE rec1 ROW(a INT, b VARCHAR(32));
+  SELECT * FROM t1 INTO rec1, rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+--error ER_OPERAND_COLUMNS
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
+
+
+--echo # ROW variables working example
+CREATE TABLE t1 (a INT, b VARCHAR(32));
+INSERT INTO t1 VALUES (10,'b10');
+DELIMITER $$;
+CREATE PROCEDURE p1()
+BEGIN
+  DECLARE rec1 ROW(a INT, b VARCHAR(32));
+  SELECT * FROM t1 INTO rec1;
+  SELECT rec1.a, rec1.b;
+END;
+$$
+DELIMITER ;$$
+CALL p1();
+DROP TABLE t1;
+DROP PROCEDURE p1;
diff --git a/sql/field.h b/sql/field.h
index 3b96dd546cb..4f29619fa85 100644
--- a/sql/field.h
+++ b/sql/field.h
@@ -4036,6 +4036,12 @@ class Spvar_definition: public Column_definition
     m_cursor_rowtype_ref(NULL),
     m_row_field_definitions(NULL)
   { }
+  const Type_handler *type_handler() const
+  {
+    return is_row() || is_table_rowtype_ref() || is_cursor_rowtype_ref() ?
+           &type_handler_row :
+           Type_handler::get_handler_by_field_type(sql_type);
+  }
   bool is_column_type_ref() const { return m_column_type_ref != 0; }
   bool is_table_rowtype_ref() const { return m_table_rowtype_ref != 0; }
   bool is_cursor_rowtype_ref() const { return m_cursor_rowtype_ref != NULL; }
diff --git a/sql/sp_pcontext.h b/sql/sp_pcontext.h
index f8ca45da4ae..98ab4955198 100644
--- a/sql/sp_pcontext.h
+++ b/sql/sp_pcontext.h
@@ -61,6 +61,9 @@ class sp_variable : public Sql_alloc
 
   /// Field-type of the SP-variable.
   enum_field_types sql_type() const { return field_def.sql_type; }
+
+  const Type_handler *type_handler() const { return field_def.type_handler(); }
+
 public:
   sp_variable(LEX_STRING _name, uint _offset)
    :Sql_alloc(),
diff --git a/sql/sql_class.cc b/sql/sql_class.cc
index 5ddb0a86592..93bc600deb9 100644
--- a/sql/sql_class.cc
+++ b/sql/sql_class.cc
@@ -3495,15 +3495,29 @@ int select_exists_subselect::send_data(List<Item> &items)
 
 int select_dumpvar::prepare(List<Item> &list, SELECT_LEX_UNIT *u)
 {
+  my_var_sp *mvsp;
   unit= u;
-  
-  if (var_list.elements != list.elements)
+  m_var_sp_row= NULL;
+
+  if (var_list.elements == 1 &&
+      (mvsp= var_list.head()->get_my_var_sp()) &&
+      mvsp->type_handler() == &type_handler_row)
   {
-    my_message(ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT,
-               ER_THD(thd, ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT), MYF(0));
-    return 1;
-  }               
-  return 0;
+    // SELECT INTO row_type_sp_variable
+    if (thd->spcont->get_item(mvsp->offset)->cols() != list.elements)
+      goto error;
+    m_var_sp_row= mvsp;
+    return 0;
+  }
+
+  // SELECT INTO variable list
+  if (var_list.elements == list.elements)
+    return 0;
+
+error:
+  my_message(ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT,
+             ER_THD(thd, ER_WRONG_NUMBER_OF_COLUMNS_IN_SELECT), MYF(0));
+  return 1;
 }
 
 
@@ -3844,12 +3858,25 @@ bool my_var_sp_row_field::set(THD *thd, Item *item)
   return thd->spcont->set_variable_row_field(thd, offset, m_field_offset, &item);
 }
 
-int select_dumpvar::send_data(List<Item> &items)
+
+bool select_dumpvar::send_data_to_var_list(List<Item> &items)
 {
+  DBUG_ENTER("select_dumpvar::send_data_to_var_list");
   List_iterator_fast<my_var> var_li(var_list);
   List_iterator<Item> it(items);
   Item *item;
   my_var *mv;
+  while ((mv= var_li++) && (item= it++))
+  {
+    if (mv->set(thd, item))
+      DBUG_RETURN(true);
+  }
+  DBUG_RETURN(false);
+}
+
+
+int select_dumpvar::send_data(List<Item> &items)
+{
   DBUG_ENTER("select_dumpvar::send_data");
 
   if (unit->offset_limit_cnt)
@@ -3862,11 +3889,11 @@ int select_dumpvar::send_data(List<Item> &items)
     my_message(ER_TOO_MANY_ROWS, ER_THD(thd, ER_TOO_MANY_ROWS), MYF(0));
     DBUG_RETURN(1);
   }
-  while ((mv= var_li++) && (item= it++))
-  {
-    if (mv->set(thd, item))
-      DBUG_RETURN(1);
-  }
+  if (m_var_sp_row ?
+      thd->spcont->set_variable_row(thd, m_var_sp_row->offset, items) :
+      send_data_to_var_list(items))
+    DBUG_RETURN(1);
+
   DBUG_RETURN(thd->is_error());
 }
 
diff --git a/sql/sql_class.h b/sql/sql_class.h
index 73d2a9f0cf6..be997a2c896 100644
--- a/sql/sql_class.h
+++ b/sql/sql_class.h
@@ -5509,21 +5509,25 @@ class my_var : public Sql_alloc  {
   my_var(const LEX_STRING& j, enum type s) : name(j), scope(s) { }
   virtual ~my_var() {}
   virtual bool set(THD *thd, Item *val) = 0;
+  virtual class my_var_sp *get_my_var_sp() { return NULL; }
 };
 
 class my_var_sp: public my_var {
+  const Type_handler *m_type_handler;
 public:
   uint offset;
-  enum_field_types type;
   /*
     Routine to which this Item_splocal belongs. Used for checking if correct
     runtime context is used for variable handling.
   */
   sp_head *sp;
-  my_var_sp(const LEX_STRING& j, uint o, enum_field_types t, sp_head *s)
-    : my_var(j, LOCAL_VAR), offset(o), type(t), sp(s) { }
+  my_var_sp(const LEX_STRING& j, uint o, const Type_handler *type_handler,
+            sp_head *s)
+    : my_var(j, LOCAL_VAR), m_type_handler(type_handler), offset(o), sp(s) { }
   ~my_var_sp() { }
   bool set(THD *thd, Item *val);
+  my_var_sp *get_my_var_sp() { return this; }
+  const Type_handler *type_handler() const { return m_type_handler; }
 };
 
 /*
@@ -5536,7 +5540,7 @@ class my_var_sp_row_field: public my_var_sp
 public:
   my_var_sp_row_field(const LEX_STRING &varname, const LEX_STRING &fieldname,
                       uint var_idx, uint field_idx, sp_head *s)
-   :my_var_sp(varname, var_idx, MYSQL_TYPE_DOUBLE/*Not really used*/, s),
+   :my_var_sp(varname, var_idx, &type_handler_double/*Not really used*/, s),
     m_field_offset(field_idx)
   { }
   bool set(THD *thd, Item *val);
@@ -5552,10 +5556,13 @@ class my_var_user: public my_var {
 
 class select_dumpvar :public select_result_interceptor {
   ha_rows row_count;
+  my_var_sp *m_var_sp_row; // Not NULL if SELECT INTO row_type_sp_variable
+  bool send_data_to_var_list(List<Item> &items);
 public:
   List<my_var> var_list;
-  select_dumpvar(THD *thd_arg): select_result_interceptor(thd_arg)
-  { var_list.empty(); row_count= 0; }
+  select_dumpvar(THD *thd_arg)
+   :select_result_interceptor(thd_arg), row_count(0), m_var_sp_row(NULL)
+  { var_list.empty(); }
   ~select_dumpvar() {}
   int prepare(List<Item> &list, SELECT_LEX_UNIT *u);
   int send_data(List<Item> &items);
diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy
index 1b87196686f..352fd5c725a 100644
--- a/sql/sql_yacc.yy
+++ b/sql/sql_yacc.yy
@@ -11706,7 +11706,7 @@ select_outvar:
             if (!Lex->spcont || !(t= Lex->spcont->find_variable($1, false)))
               my_yyabort_error((ER_SP_UNDECLARED_VAR, MYF(0), $1.str));
             $$ = Lex->result ? (new (thd->mem_root)
-                                my_var_sp($1, t->offset, t->sql_type(),
+                                my_var_sp($1, t->offset, t->type_handler(),
                                           Lex->sphead)) :
                                 NULL;
           }
diff --git a/sql/sql_yacc_ora.yy b/sql/sql_yacc_ora.yy
index 415ea119fa6..abc52c71260 100644
--- a/sql/sql_yacc_ora.yy
+++ b/sql/sql_yacc_ora.yy
@@ -11950,7 +11950,7 @@ select_outvar:
             if (!Lex->spcont || !(t= Lex->spcont->find_variable($1, false)))
               my_yyabort_error((ER_SP_UNDECLARED_VAR, MYF(0), $1.str));
             $$ = Lex->result ? (new (thd->mem_root)
-                                my_var_sp($1, t->offset, t->sql_type(),
+                                my_var_sp($1, t->offset, t->type_handler(),
                                           Lex->sphead)) :
                                 NULL;
           }
-- 
2.30.9