1
0
mirror of https://github.com/MariaDB/server.git synced 2025-07-29 05:21:33 +03:00

MDEV-31995 Bogus error executing PS for query using CTE with renaming of columns

This commit addresses column naming issues with CTEs in the use of prepared
statements and stored procedures. Usage of either prepared statements or
procedures with Common Table Expressions and column renaming may be affected.

There are three related but different issues addressed here.

1) First execution issue. Consider the following

prepare s from "with cte (col1, col2) as (select a as c1, b as c2 from t
order by c1) select col1, col2 from cte";
execute s;

After parsing, items in the select are named (c1,c2), order by (and group by)
resolution is performed, then item names are set to (col1, col2).
When the statement is executed, context analysis is again performed, but
resolution of elements in the order by statement will not be able to find c1,
because it was renamed to col1 and remains this way.

The solution is to save the names of these items during context resolution
before they have been renamed. We can then reset item names back to those after
parsing so first execution can resolve items referred to in order and group by
clauses.

2) Second Execution Issue

When the derived table contains more than one select 'unioned' together we could
reasonably think that dealing with only items in the first select (which
determines names in the resultant table) would be sufficient.  This can lead to
a different problem.  Consider

prepare st from "with cte (c1,c2) as
  (select a as col1, sum(b) as col2 from t1 where a > 0 group by col1
    union select a as col3, sum(b) as col4 from t2 where b > 2 group by col3)
  select * from cte where c1=1";

When the optimizer (only run during the first execution) pushes the outside
condition "c1=1" into every select in the derived table union, it renames the
items to make the condition valid.  In this example, this leaves the first item
in the second select named 'c1'.  The second execution will now fail 'group by'
resolution.

Again, the solution is to save the names during context analysis, resetting
before subsequent resolution, but making sure that we save/reset the item
names in all the selects in this union.

3) Memory Leak

During parsing Item::set_name() is used to allocate memory in the statement
arena.  We cannot use this call during statement execution as this represents
a memory leak.  We directly set the item list names to those in the column list
of this CTE (also allocated during parsing).

Approved by Igor Babaev <igor@mariadb.com>
This commit is contained in:
Rex
2023-09-25 12:56:30 +11:00
parent 86351f5eda
commit eb8053b377
7 changed files with 521 additions and 1 deletions

View File

@ -1784,4 +1784,162 @@ with data as (select 1 as id)
select id into @myid from data;
set sql_mode= @save_sql_mode;
--echo #
--echo # MDEV-31995 CTE column name specification inconsistency
--echo #
create table t1 (a int, b int);
insert into t1 values (1,1),(1,2),(1,3),(2,1),(2,2);
create table t2 (a int, b int);
insert into t2 values (3,1),(3,2),(3,3),(4,1),(4,2);
let $q=
with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 group by col1)
select * from cte;
eval $q;
eval prepare st from "$q";
execute st;
execute st;
drop prepare st;
eval create procedure sp() $q;
call sp();
call sp();
drop procedure sp;
let $q=
with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 order by col1)
select * from cte;
eval $q;
eval prepare st from "$q";
execute st;
execute st;
drop prepare st;
eval create procedure sp() $q;
call sp();
call sp();
drop procedure sp;
let $q=
with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 where a > 1 group by col1
union select a as col3, sum(b) as col4 from t2 where b > 2 group by col3),
cte2 (c3, c4) as
(select a as col5, sum(b) as col6 from t1 where a <= 1 group by col5
union select a as col7, sum(b) as col8 from t2 where b <= 2 group by col7)
select * from cte where c1=1 union select * from cte2 where c3=3;
eval $q;
eval prepare st from "$q";
execute st;
execute st;
drop prepare st;
eval create procedure sp() $q;
call sp();
call sp();
drop procedure sp;
let $q=
with cte (c1,c2) as (select * from t1)
select cte.c1+1 as col1 , cte.c2 as col2 from cte where cte.c1 > 1
union
select cte.c1 as col3, cte.c2+1 as col4 from cte where cte.c1 < 0;
eval $q;
eval prepare st from "$q";
execute st;
execute st;
--echo save this to the end to test errors >drop prepare st;
eval create procedure sp() $q;
call sp();
call sp();
drop procedure sp;
insert into t1 select * from t2;
let $q=
with cte (c1, c2)
as (select a, sum(b) from t1 where b > 1 group by a having sum(b) < 5)
select * from cte where c1 < 4 and c2 > 1;
eval $q;
--echo # Check pushdown conditions in JSON output
--source include/analyze-format.inc
eval explain format=json $q;
alter table t1 add column c int;
--error ER_WITH_COL_WRONG_LIST
execute st;
drop prepare st;
drop table t1,t2;
--echo Test out recursive CTEs
create table distances (src char(1), dest char(1), distance int);
create table city_population (city char(1), population int);
INSERT INTO `distances` VALUES ('A','A',0),('B','A',593),('C','A',800),
('D','A',221),('E','A',707),('F','A',869),('G','A',225),('H','A',519),
('A','B',919),('B','B',0),('C','B',440),('D','B',79),('E','B',79),
('F','B',154),('G','B',537),('H','B',220),('A','C',491),('B','C',794),
('C','C',0),('D','C',100),('E','C',350),('F','C',748),('G','C',712),
('H','C',315),('A','D',440),('B','D',256),('C','D',958),('D','D',0),
('E','D',255),('F','D',161),('G','D',63),('H','D',831),('A','E',968),
('B','E',345),('C','E',823),('D','E',81),('E','E',0),('F','E',436),
('G','E',373),('H','E',558),('A','F',670),('B','F',677),('C','F',375),
('D','F',843),('E','F',90),('F','F',0),('G','F',328),('H','F',881),
('A','G',422),('B','G',467),('C','G',67),('D','G',936),('E','G',480),
('F','G',592),('G','G',0),('H','G',819),('A','H',537),('B','H',229),
('C','H',534),('D','H',984),('E','H',319),('F','H',643),('G','H',257),
('H','H',0);
insert into city_population values ('A', 5000), ('B', 6000), ('C', 100000),
('D', 80000), ('E', 7000), ('F', 1000), ('G', 100), ('H', -80000);
--echo #find the biggest city within 300 kellikams of 'E'
let $q=
with recursive travel (src, path, dest, distance, population) as (
select city, cast('' as varchar(10)), city,
0, population
from city_population where city='E'
union all
select src.src, concat(src.path, dst.dest), dst.dest,
src.distance + dst.distance, dstc.population
from travel src
join distances dst on src.dest != dst.dest
join city_population dstc on dst.dest = dstc.city
where dst.src = src.dest and src.distance + dst.distance < 300
and length(path) < 10
)
select * from travel where dest != 'E' order by population desc, distance
limit 1;
eval $q;
eval prepare st from "$q";
execute st;
execute st;
drop prepare st;
eval create procedure sp() $q;
call sp();
call sp();
drop procedure sp;
drop table distances, city_population;
--echo # End of 10.4 tests