MDEV-29307 Wrong result when joining two derived tables over the same view

This bug could affect queries containing a join of derived tables over
grouping views such that one of the derived tables contains a window
function while another uses view V with dependent subquery DSQ containing
a set function aggregated outside of the subquery in the view V. The
subquery also refers to the fields from the group clause of the view.Due to
this bug execution of such queries could produce wrong result sets.

When the fix_fields() method performs context analysis of a set function AF
first, at the very beginning the function Item_sum::init_sum_func_check()
is called. The function copies the pointer to the embedding set function,
if any, stored in THD::LEX::in_sum_func into the corresponding field of the
set function AF simultaneously changing the value of THD::LEX::in_sum_func
to point to AF. When at the very end of the fix_fields() method the function
Item_sum::check_sum_func() is called it is supposed to restore the value
of THD::LEX::in_sum_func to point to the embedding set function. And in
fact Item_sum::check_sum_func() did it, but only for regular set functions,
not for those used in window functions. As a result after the context
analysis of AF had finished THD::LEX::in_sum_func still pointed to AF.
It confused the further context analysis. In particular it led to wrong
resolution of Item_outer_ref objects in the fix_inner_refs() function.
This wrong resolution forced reading the values of grouping fields referred
in DSQ not from the temporary table used for aggregation from which they
were supposed to be read, but from the table used as the source table for
aggregation.

This patch guarantees that the value of THD::LEX::in_sum_func is properly
restored after the call of fix_fields() for any set function.
This commit is contained in:
Igor Babaev 2024-06-01 01:11:40 -07:00
parent 042a0d85ad
commit 4d38267fc7
4 changed files with 445 additions and 0 deletions

View file

@ -4391,3 +4391,177 @@ row_number() OVER (order by a)
2
3
drop table t1;
#
# MDEV-29307: join of 2 derived tables over the same grouping view such
# that the first of the joined tables contains a window
# function and the view's specification contains a subquery
# with a set function aggregated on the top level
#
CREATE TABLE t1 (
tst int NOT NULL,
flat tinyint unsigned NOT NULL,
type tinyint unsigned NOT NULL,
val int NOT NULL,
PRIMARY KEY (tst,flat,type)
) ENGINE=ARIA;
INSERT INTO t1 VALUES
(5, 20, 2, 100),
(7, 20, 2, 150),
(9, 20, 1, 200);
CREATE VIEW v1 AS (
SELECT
flat,
type,
( SELECT val FROM t1 sw
WHERE sw.tst = MAX(w.tst) AND sw.flat = w.flat AND sw.type = w.type)
AS total
FROM t1 w
GROUP BY flat, type
);
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived4> ALL NULL NULL NULL NULL 3 100.00 Using where
1 PRIMARY <derived6> ref key0 key0 1 v1.flat 2 100.00 Using where
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
Warnings:
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
Note 1003 /* select#1 */ select `v1`.`total` AS `w2_total`,`v1`.`total` AS `w1_total` from `test`.`v1` join `test`.`v1` where `v1`.`flat` = `v1`.`flat` and `v1`.`type` = 2 and `v1`.`type` = 1
SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
w2_total w1_total
150 200
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 100.00 Using where
1 PRIMARY <derived6> ref key0 key0 1 w1.flat 2 100.00 Using where
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
2 DERIVED <derived4> ALL NULL NULL NULL NULL 3 100.00 Using where; Using temporary
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
Warnings:
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
Note 1003 /* select#1 */ select `v1`.`total` AS `w2_total`,`w1`.`total` AS `w1_total` from (/* select#2 */ select `v1`.`flat` AS `flat`,`v1`.`type` AS `type`,`v1`.`total` AS `total`,count(`v1`.`total`) over ( partition by `v1`.`type` order by `v1`.`type`) AS `u` from `test`.`v1` where `v1`.`type` = 1) `w1` join `test`.`v1` where `v1`.`flat` = `w1`.`flat` and `v1`.`type` = 2
SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
w2_total w1_total
150 200
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total, u
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
FROM v1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
) AS w2;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 100.00
1 PRIMARY <derived6> ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join)
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using index; Using temporary; Using filesort
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
2 DERIVED <derived4> ALL NULL NULL NULL NULL 3 100.00 Using temporary
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using index; Using temporary; Using filesort
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
Warnings:
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
Note 1003 /* select#1 */ select `v1`.`total` AS `w2_total`,`w1`.`total` AS `w1_total`,`w1`.`u` AS `u` from (/* select#2 */ select `v1`.`flat` AS `flat`,`v1`.`type` AS `type`,`v1`.`total` AS `total`,count(`v1`.`total`) over ( partition by `v1`.`flat` order by `v1`.`flat`) AS `u` from `test`.`v1`) `w1` join `test`.`v1`
SELECT w2.total AS w2_total, w1.total AS w1_total, u
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
FROM v1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
) AS w2;
w2_total w1_total u
150 150 2
150 200 2
200 150 2
200 200 2
DROP VIEW v1;
DROP TABLE t1;
# End of 10.5 tests

View file

@ -2873,3 +2873,96 @@ create table t1 (a int);
insert into t1 values (1),(2),(3);
SELECT row_number() OVER (order by a) FROM t1 order by NAME_CONST('myname',NULL);
drop table t1;
--echo #
--echo # MDEV-29307: join of 2 derived tables over the same grouping view such
--echo # that the first of the joined tables contains a window
--echo # function and the view's specification contains a subquery
--echo # with a set function aggregated on the top level
--echo #
CREATE TABLE t1 (
tst int NOT NULL,
flat tinyint unsigned NOT NULL,
type tinyint unsigned NOT NULL,
val int NOT NULL,
PRIMARY KEY (tst,flat,type)
) ENGINE=ARIA;
INSERT INTO t1 VALUES
(5, 20, 2, 100),
(7, 20, 2, 150),
(9, 20, 1, 200);
CREATE VIEW v1 AS (
SELECT
flat,
type,
( SELECT val FROM t1 sw
WHERE sw.tst = MAX(w.tst) AND sw.flat = w.flat AND sw.type = w.type)
AS total
FROM t1 w
GROUP BY flat, type
);
let $q1=
SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
eval EXPLAIN EXTENDED $q1;
eval $q1;
let $q2=
SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
eval EXPLAIN EXTENDED $q2;
eval $q2;
let $q3=
SELECT w2.total AS w2_total, w1.total AS w1_total, u
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
FROM v1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
) AS w2;
eval EXPLAIN EXTENDED $q3;
--sorted_result
eval $q3;
DROP VIEW v1;
DROP TABLE t1;
--echo # End of 10.5 tests

View file

@ -4398,6 +4398,180 @@ row_number() OVER (order by a)
3
drop table t1;
#
# MDEV-29307: join of 2 derived tables over the same grouping view such
# that the first of the joined tables contains a window
# function and the view's specification contains a subquery
# with a set function aggregated on the top level
#
CREATE TABLE t1 (
tst int NOT NULL,
flat tinyint unsigned NOT NULL,
type tinyint unsigned NOT NULL,
val int NOT NULL,
PRIMARY KEY (tst,flat,type)
) ENGINE=ARIA;
INSERT INTO t1 VALUES
(5, 20, 2, 100),
(7, 20, 2, 150),
(9, 20, 1, 200);
CREATE VIEW v1 AS (
SELECT
flat,
type,
( SELECT val FROM t1 sw
WHERE sw.tst = MAX(w.tst) AND sw.flat = w.flat AND sw.type = w.type)
AS total
FROM t1 w
GROUP BY flat, type
);
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived4> ALL NULL NULL NULL NULL 3 100.00 Using where
1 PRIMARY <derived6> ref key0 key0 1 v1.flat 2 100.00 Using where
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
Warnings:
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
Note 1003 /* select#1 */ select `v1`.`total` AS `w2_total`,`v1`.`total` AS `w1_total` from `test`.`v1` join `test`.`v1` where `v1`.`flat` = `v1`.`flat` and `v1`.`type` = 2 and `v1`.`type` = 1
SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
w2_total w1_total
150 200
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 100.00 Using where
1 PRIMARY <derived6> ref key0 key0 1 w1.flat 2 100.00 Using where
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
2 DERIVED <derived4> ALL NULL NULL NULL NULL 3 100.00 Using where; Using temporary
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
Warnings:
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
Note 1003 /* select#1 */ select `v1`.`total` AS `w2_total`,`w1`.`total` AS `w1_total` from (/* select#2 */ select `v1`.`flat` AS `flat`,`v1`.`type` AS `type`,`v1`.`total` AS `total`,count(`v1`.`total`) over ( partition by `v1`.`type` order by `v1`.`type`) AS `u` from `test`.`v1` where `v1`.`type` = 1) `w1` join `test`.`v1` where `v1`.`flat` = `w1`.`flat` and `v1`.`type` = 2
SELECT w2.total AS w2_total, w1.total AS w1_total
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
FROM v1
WHERE type = 1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
WHERE type = 2
) AS w2
ON w1.flat = w2.flat;
w2_total w1_total
150 200
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total, u
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
FROM v1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
) AS w2;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 100.00
1 PRIMARY <derived6> ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join)
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using index; Using temporary; Using filesort
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
2 DERIVED <derived4> ALL NULL NULL NULL NULL 3 100.00 Using temporary
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using index; Using temporary; Using filesort
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
Warnings:
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
Note 1003 /* select#1 */ select `v1`.`total` AS `w2_total`,`w1`.`total` AS `w1_total`,`w1`.`u` AS `u` from (/* select#2 */ select `v1`.`flat` AS `flat`,`v1`.`type` AS `type`,`v1`.`total` AS `total`,count(`v1`.`total`) over ( partition by `v1`.`flat` order by `v1`.`flat`) AS `u` from `test`.`v1`) `w1` join `test`.`v1`
SELECT w2.total AS w2_total, w1.total AS w1_total, u
FROM
(
SELECT flat, type, total,
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
FROM v1
) AS w1
JOIN
(
SELECT flat, type, total
FROM v1
) AS w2;
w2_total w1_total u
150 150 2
150 200 2
200 150 2
200 200 2
DROP VIEW v1;
DROP TABLE t1;
# End of 10.5 tests
#
# MDEV-23867: select crash in compute_window_func
#
set @save_sort_buffer_size=@@sort_buffer_size;

View file

@ -177,7 +177,11 @@ bool Item_sum::check_sum_func(THD *thd, Item **ref)
}
if (window_func_sum_expr_flag)
{
thd->lex->in_sum_func= in_sum_func;
return false;
}
/*
The value of max_arg_level is updated if an argument of the set function
contains a column reference resolved against a subquery whose level is