Skip to content

Commit 4d38267

Browse files
committed
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.
1 parent 042a0d8 commit 4d38267

File tree

4 files changed

+445
-0
lines changed

4 files changed

+445
-0
lines changed

mysql-test/main/win.result

Lines changed: 174 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -4391,3 +4391,177 @@ row_number() OVER (order by a)
43914391
2
43924392
3
43934393
drop table t1;
4394+
#
4395+
# MDEV-29307: join of 2 derived tables over the same grouping view such
4396+
# that the first of the joined tables contains a window
4397+
# function and the view's specification contains a subquery
4398+
# with a set function aggregated on the top level
4399+
#
4400+
CREATE TABLE t1 (
4401+
tst int NOT NULL,
4402+
flat tinyint unsigned NOT NULL,
4403+
type tinyint unsigned NOT NULL,
4404+
val int NOT NULL,
4405+
PRIMARY KEY (tst,flat,type)
4406+
) ENGINE=ARIA;
4407+
INSERT INTO t1 VALUES
4408+
(5, 20, 2, 100),
4409+
(7, 20, 2, 150),
4410+
(9, 20, 1, 200);
4411+
CREATE VIEW v1 AS (
4412+
SELECT
4413+
flat,
4414+
type,
4415+
( SELECT val FROM t1 sw
4416+
WHERE sw.tst = MAX(w.tst) AND sw.flat = w.flat AND sw.type = w.type)
4417+
AS total
4418+
FROM t1 w
4419+
GROUP BY flat, type
4420+
);
4421+
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total
4422+
FROM
4423+
(
4424+
SELECT flat, type, total
4425+
FROM v1
4426+
WHERE type = 1
4427+
) AS w1
4428+
JOIN
4429+
(
4430+
SELECT flat, type, total
4431+
FROM v1
4432+
WHERE type = 2
4433+
) AS w2
4434+
ON w1.flat = w2.flat;
4435+
id select_type table type possible_keys key key_len ref rows filtered Extra
4436+
1 PRIMARY <derived4> ALL NULL NULL NULL NULL 3 100.00 Using where
4437+
1 PRIMARY <derived6> ref key0 key0 1 v1.flat 2 100.00 Using where
4438+
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
4439+
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4440+
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
4441+
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4442+
Warnings:
4443+
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
4444+
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
4445+
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
4446+
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
4447+
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
4448+
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
4449+
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
4450+
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
4451+
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
4452+
SELECT w2.total AS w2_total, w1.total AS w1_total
4453+
FROM
4454+
(
4455+
SELECT flat, type, total
4456+
FROM v1
4457+
WHERE type = 1
4458+
) AS w1
4459+
JOIN
4460+
(
4461+
SELECT flat, type, total
4462+
FROM v1
4463+
WHERE type = 2
4464+
) AS w2
4465+
ON w1.flat = w2.flat;
4466+
w2_total w1_total
4467+
150 200
4468+
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total
4469+
FROM
4470+
(
4471+
SELECT flat, type, total,
4472+
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
4473+
FROM v1
4474+
WHERE type = 1
4475+
) AS w1
4476+
JOIN
4477+
(
4478+
SELECT flat, type, total
4479+
FROM v1
4480+
WHERE type = 2
4481+
) AS w2
4482+
ON w1.flat = w2.flat;
4483+
id select_type table type possible_keys key key_len ref rows filtered Extra
4484+
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 100.00 Using where
4485+
1 PRIMARY <derived6> ref key0 key0 1 w1.flat 2 100.00 Using where
4486+
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
4487+
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4488+
2 DERIVED <derived4> ALL NULL NULL NULL NULL 3 100.00 Using where; Using temporary
4489+
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using where; Using index; Using temporary; Using filesort
4490+
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4491+
Warnings:
4492+
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
4493+
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
4494+
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
4495+
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
4496+
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
4497+
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
4498+
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
4499+
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
4500+
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
4501+
SELECT w2.total AS w2_total, w1.total AS w1_total
4502+
FROM
4503+
(
4504+
SELECT flat, type, total,
4505+
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
4506+
FROM v1
4507+
WHERE type = 1
4508+
) AS w1
4509+
JOIN
4510+
(
4511+
SELECT flat, type, total
4512+
FROM v1
4513+
WHERE type = 2
4514+
) AS w2
4515+
ON w1.flat = w2.flat;
4516+
w2_total w1_total
4517+
150 200
4518+
EXPLAIN EXTENDED SELECT w2.total AS w2_total, w1.total AS w1_total, u
4519+
FROM
4520+
(
4521+
SELECT flat, type, total,
4522+
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
4523+
FROM v1
4524+
) AS w1
4525+
JOIN
4526+
(
4527+
SELECT flat, type, total
4528+
FROM v1
4529+
) AS w2;
4530+
id select_type table type possible_keys key key_len ref rows filtered Extra
4531+
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 3 100.00
4532+
1 PRIMARY <derived6> ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join)
4533+
6 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using index; Using temporary; Using filesort
4534+
7 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4535+
2 DERIVED <derived4> ALL NULL NULL NULL NULL 3 100.00 Using temporary
4536+
4 DERIVED w index NULL PRIMARY 6 NULL 3 100.00 Using index; Using temporary; Using filesort
4537+
5 DEPENDENT SUBQUERY sw eq_ref PRIMARY PRIMARY 6 func,func,func 1 100.00 Using index condition
4538+
Warnings:
4539+
Note 1276 Field or reference 'test.w.tst' of SELECT #5 was resolved in SELECT #4
4540+
Note 1981 Aggregate function 'max()' of SELECT #5 belongs to SELECT #4
4541+
Note 1276 Field or reference 'test.w.flat' of SELECT #5 was resolved in SELECT #4
4542+
Note 1276 Field or reference 'test.w.type' of SELECT #5 was resolved in SELECT #4
4543+
Note 1276 Field or reference 'test.w.tst' of SELECT #7 was resolved in SELECT #6
4544+
Note 1981 Aggregate function 'max()' of SELECT #7 belongs to SELECT #6
4545+
Note 1276 Field or reference 'test.w.flat' of SELECT #7 was resolved in SELECT #6
4546+
Note 1276 Field or reference 'test.w.type' of SELECT #7 was resolved in SELECT #6
4547+
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`
4548+
SELECT w2.total AS w2_total, w1.total AS w1_total, u
4549+
FROM
4550+
(
4551+
SELECT flat, type, total,
4552+
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
4553+
FROM v1
4554+
) AS w1
4555+
JOIN
4556+
(
4557+
SELECT flat, type, total
4558+
FROM v1
4559+
) AS w2;
4560+
w2_total w1_total u
4561+
150 150 2
4562+
150 200 2
4563+
200 150 2
4564+
200 200 2
4565+
DROP VIEW v1;
4566+
DROP TABLE t1;
4567+
# End of 10.5 tests

mysql-test/main/win.test

Lines changed: 93 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2873,3 +2873,96 @@ create table t1 (a int);
28732873
insert into t1 values (1),(2),(3);
28742874
SELECT row_number() OVER (order by a) FROM t1 order by NAME_CONST('myname',NULL);
28752875
drop table t1;
2876+
2877+
--echo #
2878+
--echo # MDEV-29307: join of 2 derived tables over the same grouping view such
2879+
--echo # that the first of the joined tables contains a window
2880+
--echo # function and the view's specification contains a subquery
2881+
--echo # with a set function aggregated on the top level
2882+
--echo #
2883+
2884+
CREATE TABLE t1 (
2885+
tst int NOT NULL,
2886+
flat tinyint unsigned NOT NULL,
2887+
type tinyint unsigned NOT NULL,
2888+
val int NOT NULL,
2889+
PRIMARY KEY (tst,flat,type)
2890+
) ENGINE=ARIA;
2891+
2892+
INSERT INTO t1 VALUES
2893+
(5, 20, 2, 100),
2894+
(7, 20, 2, 150),
2895+
(9, 20, 1, 200);
2896+
2897+
CREATE VIEW v1 AS (
2898+
SELECT
2899+
flat,
2900+
type,
2901+
( SELECT val FROM t1 sw
2902+
WHERE sw.tst = MAX(w.tst) AND sw.flat = w.flat AND sw.type = w.type)
2903+
AS total
2904+
FROM t1 w
2905+
GROUP BY flat, type
2906+
);
2907+
2908+
let $q1=
2909+
SELECT w2.total AS w2_total, w1.total AS w1_total
2910+
FROM
2911+
(
2912+
SELECT flat, type, total
2913+
FROM v1
2914+
WHERE type = 1
2915+
) AS w1
2916+
JOIN
2917+
(
2918+
SELECT flat, type, total
2919+
FROM v1
2920+
WHERE type = 2
2921+
) AS w2
2922+
ON w1.flat = w2.flat;
2923+
2924+
eval EXPLAIN EXTENDED $q1;
2925+
eval $q1;
2926+
2927+
let $q2=
2928+
SELECT w2.total AS w2_total, w1.total AS w1_total
2929+
FROM
2930+
(
2931+
SELECT flat, type, total,
2932+
COUNT(total) OVER (PARTITION BY type ORDER BY type) AS u
2933+
FROM v1
2934+
WHERE type = 1
2935+
) AS w1
2936+
JOIN
2937+
(
2938+
SELECT flat, type, total
2939+
FROM v1
2940+
WHERE type = 2
2941+
) AS w2
2942+
ON w1.flat = w2.flat;
2943+
2944+
eval EXPLAIN EXTENDED $q2;
2945+
eval $q2;
2946+
2947+
let $q3=
2948+
SELECT w2.total AS w2_total, w1.total AS w1_total, u
2949+
FROM
2950+
(
2951+
SELECT flat, type, total,
2952+
COUNT(total) OVER (PARTITION BY flat ORDER BY flat) AS u
2953+
FROM v1
2954+
) AS w1
2955+
JOIN
2956+
(
2957+
SELECT flat, type, total
2958+
FROM v1
2959+
) AS w2;
2960+
2961+
eval EXPLAIN EXTENDED $q3;
2962+
--sorted_result
2963+
eval $q3;
2964+
2965+
DROP VIEW v1;
2966+
DROP TABLE t1;
2967+
2968+
--echo # End of 10.5 tests

0 commit comments

Comments
 (0)