Commit a5a9fcdf authored by Monty's avatar Monty

MDEV-12325 Unexpected data type and truncation when using CTE

When creating a recursive CTE, the column types are taken from the
non recursive part of the CTE (this is according to the SQL standard).

This patch adds code to abort the CTE if the calculated values in the
recursive part does not fit in the fields in the created temporary table.

The new code only affects recursive CTE, so it should not cause any notable
problems for old applications.

Other things:
- Fixed that we get correct row numbers for warnings generated with
  WITH RECURSIVE

Reviewer: Alexander Barkov <bar@mariadb.com>
parent 43c7f6a0
......@@ -4873,4 +4873,149 @@ a
0
NULL
DROP TABLE t1;
#
# MDEV-12325 Unexpected data type and truncation when using CTE
#
CREATE TABLE t1
(
id INT, mid INT, name TEXT
);
INSERT INTO t1 VALUES (0,NULL,'Name'),(1,0,'Name1'),(2,0,'Name2'),(11,1,'Name11'),(12,1,'Name12');
WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;
ERROR 22003: Out of range value for column 'mid' at row 2
create table t2 as WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;;
ERROR 22003: Out of range value for column 'mid' at row 2
create table t2 ignore as WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;;
Warnings:
Warning 1264 Out of range value for column 'mid' at row 2
Warning 1264 Out of range value for column 'mid' at row 3
Warning 1264 Out of range value for column 'mid' at row 4
Warning 1264 Out of range value for column 'mid' at row 5
show create table t2;
Table Create Table
t2 CREATE TABLE `t2` (
`level` int(1) DEFAULT NULL,
`id` int(11) DEFAULT NULL,
`mid` int(11) DEFAULT NULL,
`name` text DEFAULT NULL,
`mname` text DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
insert into t2 WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;;
ERROR 22003: Out of range value for column 'mid' at row 2
insert ignore into t2 WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;;
Warnings:
Warning 1264 Out of range value for column 'mid' at row 2
Warning 1264 Out of range value for column 'mid' at row 3
Warning 1264 Out of range value for column 'mid' at row 4
Warning 1264 Out of range value for column 'mid' at row 5
drop table t2;
set @@sql_mode="";
WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;
level id mid name mname
1 0 NULL Name NULL
2 1 2147483647 Name1 NULL
2 2 2147483647 Name2 NULL
3 11 2147483647 Name11 NULL
3 12 2147483647 Name12 NULL
Warnings:
Warning 1264 Out of range value for column 'mid' at row 2
Warning 1264 Out of range value for column 'mid' at row 3
Warning 1264 Out of range value for column 'mid' at row 4
Warning 1264 Out of range value for column 'mid' at row 5
create table t2 as WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;;
Warnings:
Warning 1264 Out of range value for column 'mid' at row 2
Warning 1264 Out of range value for column 'mid' at row 3
Warning 1264 Out of range value for column 'mid' at row 4
Warning 1264 Out of range value for column 'mid' at row 5
show create table t2;
Table Create Table
t2 CREATE TABLE `t2` (
`level` int(1) DEFAULT NULL,
`id` int(11) DEFAULT NULL,
`mid` int(11) DEFAULT NULL,
`name` text DEFAULT NULL,
`mname` text DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
set @@sql_mode=default;
drop table t1,t2;
#
# End of 10.3 tests
#
......@@ -3165,4 +3165,47 @@ SELECT * FROM cte;
DROP TABLE t1;
--echo #
--echo # MDEV-12325 Unexpected data type and truncation when using CTE
--echo #
CREATE TABLE t1
(
id INT, mid INT, name TEXT
);
INSERT INTO t1 VALUES (0,NULL,'Name'),(1,0,'Name1'),(2,0,'Name2'),(11,1,'Name11'),(12,1,'Name12');
let $query=
WITH RECURSIVE
cteReports (level, id, mid, name) AS
(
SELECT 1, id, mid, name FROM t1 WHERE mid IS NULL
UNION ALL
SELECT r.level + 1, e.id, e.mid + 1000000000000, e.name FROM t1 e
INNER JOIN cteReports r ON e.mid = r.id
)
SELECT
level, id, mid, name,
(SELECT name FROM t1 WHERE id= cteReports.mid) AS mname
FROM cteReports ORDER BY level, mid;
--error ER_WARN_DATA_OUT_OF_RANGE
--eval $query
--error ER_WARN_DATA_OUT_OF_RANGE
--eval create table t2 as $query;
--eval create table t2 ignore as $query;
show create table t2;
--error ER_WARN_DATA_OUT_OF_RANGE
--eval insert into t2 $query;
--eval insert ignore into t2 $query;
drop table t2;
set @@sql_mode="";
--eval $query
--eval create table t2 as $query;
show create table t2;
set @@sql_mode=default;
drop table t1,t2;
--echo #
--echo # End of 10.3 tests
--echo #
......@@ -5691,10 +5691,12 @@ class select_union_recursive :public select_unit
or for the unit specifying a CTE that mutually recursive with this CTE.
*/
uint cleanup_count;
long row_counter;
select_union_recursive(THD *thd_arg):
select_unit(thd_arg),
incr_table(0), first_rec_table_to_update(0), cleanup_count(0)
incr_table(0), first_rec_table_to_update(0), cleanup_count(0),
row_counter(0)
{ incr_table_param.init(); };
int send_data(List<Item> &items);
......
......@@ -722,6 +722,13 @@ class Warning_info
/** Reset the current row counter. Start counting from the first row. */
void reset_current_row_for_warning() { m_current_row_for_warning= 1; }
ulong set_current_row_for_warning(ulong row)
{
ulong old_row= m_current_row_for_warning;
m_current_row_for_warning= row;
return old_row;
}
/** Return the current counter value. */
ulong current_row_for_warning() const { return m_current_row_for_warning; }
......@@ -1099,6 +1106,9 @@ class Diagnostics_area: public Sql_state_errno,
void opt_clear_warning_info(ulonglong query_id)
{ get_warning_info()->opt_clear(query_id); }
long set_current_row_for_warning(long row)
{ return get_warning_info()->set_current_row_for_warning(row); }
ulong current_row_for_warning() const
{ return get_warning_info()->current_row_for_warning(); }
......
......@@ -297,7 +297,27 @@ bool select_unit::send_eof()
int select_union_recursive::send_data(List<Item> &values)
{
int rc= select_unit::send_data(values);
int rc;
bool save_abort_on_warning= thd->abort_on_warning;
enum_check_fields save_count_cuted_fields= thd->count_cuted_fields;
long save_counter;
/*
For recursive CTE's give warnings for wrong field info
However, we don't do that for CREATE TABLE ... SELECT or INSERT ... SELECT
as the upper level code for these handles setting of abort_on_warning
depending on if 'IGNORE' is used.
*/
if (thd->lex->sql_command != SQLCOM_CREATE_TABLE &&
thd->lex->sql_command != SQLCOM_INSERT_SELECT)
thd->abort_on_warning= thd->is_strict_mode();
thd->count_cuted_fields= CHECK_FIELD_WARN;
save_counter= thd->get_stmt_da()->set_current_row_for_warning(++row_counter);
rc= select_unit::send_data(values);
thd->get_stmt_da()->set_current_row_for_warning(save_counter);
thd->count_cuted_fields= save_count_cuted_fields;
thd->abort_on_warning= save_abort_on_warning;
if (rc == 0 &&
write_err != HA_ERR_FOUND_DUPP_KEY &&
......@@ -476,6 +496,7 @@ void select_union_recursive::cleanup()
thd->rec_tables= tab;
tbl->derived_result= 0;
}
row_counter= 0;
}
......
......@@ -15373,7 +15373,6 @@ with_clause:
MYSQL_YYABORT;
Lex->derived_tables|= DERIVED_WITH;
Lex->with_cte_resolution= true;
Lex->with_cte_resolution= true;
Lex->curr_with_clause= with_clause;
with_clause->add_to_list(Lex->with_clauses_list_last_next);
}
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment