Skip to content

Commit 374ec82

Browse files
committed
MDEV-24597 Explicit column name error in CTE of UNION
This bug manifested itself when executing queries with multiple reference to a CTE specified by a query expression with union and having its column names explicitly declared. In this case the server returned a bogus error message about unknown column name. It happened because while for the first reference to the CTE the names of the columns returned by the CTE specification were properly changed to match the CTE definition for the other references it was not done. This was a consequence of not quite complete code of the function With_element::clone_parsed_spec() that forgot to set the reference to the CTE definition for unit structures representing non-first CTE references. Approved by dmitry.shulga@mariadb.com
1 parent 90780bb commit 374ec82

File tree

3 files changed

+72
-2
lines changed

3 files changed

+72
-2
lines changed

mysql-test/r/cte_nonrecursive.result

Lines changed: 40 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -618,7 +618,7 @@ with t(c) as (select a from t1 where b >= 'c')
618618
select * from t r1, t r2 where r1.c=r2.c and r2.c=4;
619619
show create view v4;
620620
View Create View character_set_client collation_connection
621-
v4 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v4` AS with t as (select `test`.`t1`.`a` AS `c` from `test`.`t1` where `test`.`t1`.`b` >= 'c')select `r1`.`c` AS `c`,`r2`.`c` AS `d` from (`t` `r1` join (select `test`.`t1`.`a` AS `c` from `test`.`t1` where `test`.`t1`.`b` >= 'c') `r2`) where `r1`.`c` = `r2`.`c` and `r2`.`c` = 4 latin1 latin1_swedish_ci
621+
v4 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v4` AS with t as (select `test`.`t1`.`a` AS `c` from `test`.`t1` where `test`.`t1`.`b` >= 'c')select `r1`.`c` AS `c`,`r2`.`c` AS `d` from (`t` `r1` join `t` `r2`) where `r1`.`c` = `r2`.`c` and `r2`.`c` = 4 latin1 latin1_swedish_ci
622622
select * from v4;
623623
c d
624624
4 4
@@ -1126,7 +1126,7 @@ NULL UNION RESULT <union2,5> ALL NULL NULL NULL NULL NULL NULL
11261126
NULL UNION RESULT <union9,12> ALL NULL NULL NULL NULL NULL NULL
11271127
NULL UNION RESULT <union1,6> ALL NULL NULL NULL NULL NULL NULL
11281128
Warnings:
1129-
Note 1003 with cte_e as (with cte_o as (with cte_i as (select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1 union select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1)select `cte_e1`.`a` AS `a` from `cte_e` `cte_e1` where `cte_e1`.`a` > 1 union select `cte_e2`.`a` AS `a` from (with cte_o as (with cte_i as (select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 union select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7) `cte_e2`
1129+
Note 1003 with cte_e as (with cte_o as (with cte_i as (select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 7)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1)select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` < 3 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1 union select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 4 and `test`.`t1`.`a` > 1 and `test`.`t1`.`a` < 7 and `test`.`t1`.`a` > 1)select `cte_e1`.`a` AS `a` from `cte_e` `cte_e1` where `cte_e1`.`a` > 1 union select `cte_e2`.`a` AS `a` from `cte_e` `cte_e2`
11301130
drop table t1;
11311131
#
11321132
# MDEV-13753: embedded CTE in a VIEW created in prepared statement
@@ -1725,4 +1725,42 @@ drop table db1.t1;
17251725
drop database db1;
17261726
create database test;
17271727
use test;
1728+
#
1729+
# MDEV-24597: CTE with union used multiple times in query
1730+
#
1731+
with cte(a) as
1732+
(select 1 as d union select 2 as d)
1733+
select a from cte as r1
1734+
union
1735+
select a from cte as r2;
1736+
a
1737+
1
1738+
2
1739+
create table t1 (a int, b int) engine=myisam;
1740+
insert into t1 values
1741+
(3,30), (7,70), (1,10), (7,71), (2,20), (7,72), (3,33), (4,44),
1742+
(5,50), (4,40), (3,33), (4,42), (4,43), (5,51);
1743+
with cte(c) as
1744+
(select a from t1 where b < 30 union select a from t1 where b > 40)
1745+
select * from cte as r1, cte as r2 where r1.c = r2.c;
1746+
c c
1747+
1 1
1748+
2 2
1749+
7 7
1750+
4 4
1751+
5 5
1752+
with cte(a,c) as
1753+
(
1754+
select a, count(*) from t1 group by a having count(*) = 1
1755+
union
1756+
select a, count(*) from t1 group by a having count(*) = 3
1757+
)
1758+
select a, c from cte as r1 where a < 3
1759+
union
1760+
select a, c from cte as r2 where a > 4;
1761+
a c
1762+
1 1
1763+
2 1
1764+
7 3
1765+
drop table t1;
17281766
# End of 10.2 tests

mysql-test/t/cte_nonrecursive.test

Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1230,4 +1230,35 @@ drop database db1;
12301230
create database test;
12311231
use test;
12321232

1233+
--echo #
1234+
--echo # MDEV-24597: CTE with union used multiple times in query
1235+
--echo #
1236+
1237+
with cte(a) as
1238+
(select 1 as d union select 2 as d)
1239+
select a from cte as r1
1240+
union
1241+
select a from cte as r2;
1242+
1243+
create table t1 (a int, b int) engine=myisam;
1244+
insert into t1 values
1245+
(3,30), (7,70), (1,10), (7,71), (2,20), (7,72), (3,33), (4,44),
1246+
(5,50), (4,40), (3,33), (4,42), (4,43), (5,51);
1247+
1248+
with cte(c) as
1249+
(select a from t1 where b < 30 union select a from t1 where b > 40)
1250+
select * from cte as r1, cte as r2 where r1.c = r2.c;
1251+
1252+
with cte(a,c) as
1253+
(
1254+
select a, count(*) from t1 group by a having count(*) = 1
1255+
union
1256+
select a, count(*) from t1 group by a having count(*) = 3
1257+
)
1258+
select a, c from cte as r1 where a < 3
1259+
union
1260+
select a, c from cte as r2 where a > 4;
1261+
1262+
drop table t1;
1263+
12331264
--echo # End of 10.2 tests

sql/sql_cte.cc

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -879,6 +879,7 @@ st_select_lex_unit *With_element::clone_parsed_spec(THD *thd,
879879
with_table->next_global= spec_tables;
880880
}
881881
res= &lex->unit;
882+
res->with_element= this;
882883

883884
lex->unit.include_down(with_table->select_lex);
884885
lex->unit.set_slave(with_select);

0 commit comments

Comments
 (0)