Skip to content

Commit ac78927

Browse files
committed
Fixed bug mdev-7992.
'Not exists' optimization can be used for nested outer joins only if IS NULL predicate from the WHERE condition is activated. So we have to check that all guards that wrap this predicate are in the 'open' state. This patch supports usage of 'Not exists' optimization for any outer join, no matter how it's nested in other outer joins. This patch is also considered as a proper fix for bugs #49322/#58490 and LP #817360.
1 parent bdb672f commit ac78927

File tree

4 files changed

+294
-40
lines changed

4 files changed

+294
-40
lines changed

mysql-test/r/join_nested.result

Lines changed: 95 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1870,4 +1870,99 @@ f4
18701870
NULL
18711871
NULL
18721872
DROP TABLE t1,t2,t3,t4,t5;
1873+
#
1874+
# MDEV-7992: Nested left joins + 'not exists' optimization
1875+
#
1876+
CREATE TABLE t1(
1877+
K1 INT PRIMARY KEY,
1878+
Name VARCHAR(15)
1879+
);
1880+
INSERT INTO t1 VALUES
1881+
(1,'T1Row1'), (2,'T1Row2');
1882+
CREATE TABLE t2(
1883+
K2 INT PRIMARY KEY,
1884+
K1r INT,
1885+
rowTimestamp DATETIME,
1886+
Event VARCHAR(15)
1887+
);
1888+
INSERT INTO t2 VALUES
1889+
(1, 1, '2015-04-13 10:42:11' ,'T1Row1Event1'),
1890+
(2, 1, '2015-04-13 10:42:12' ,'T1Row1Event2'),
1891+
(3, 1, '2015-04-13 10:42:12' ,'T1Row1Event3');
1892+
SELECT t1a.*, t2a.*,
1893+
t2i.K2 AS K2B, t2i.K1r AS K1rB,
1894+
t2i.rowTimestamp AS rowTimestampB, t2i.Event AS EventB
1895+
FROM
1896+
t1 t1a JOIN t2 t2a ON t2a.K1r = t1a.K1
1897+
LEFT JOIN
1898+
( t1 t1i LEFT JOIN t2 t2i ON t2i.K1r = t1i.K1)
1899+
ON (t1i.K1 = 1) AND
1900+
(((t2i.K1r = t1a.K1 AND t2i.rowTimestamp > t2a.rowTimestamp ) OR
1901+
(t2i.rowTimestamp = t2a.rowTimestamp AND t2i.K2 > t2a.K2))
1902+
OR (t2i.K2 IS NULL))
1903+
WHERE
1904+
t2a.K1r = 1 AND t2i.K2 IS NULL;
1905+
K1 Name K2 K1r rowTimestamp Event K2B K1rB rowTimestampB EventB
1906+
1 T1Row1 3 1 2015-04-13 10:42:12 T1Row1Event3 NULL NULL NULL NULL
1907+
EXPLAIN EXTENDED SELECT t1a.*, t2a.*,
1908+
t2i.K2 AS K2B, t2i.K1r AS K1rB,
1909+
t2i.rowTimestamp AS rowTimestampB, t2i.Event AS EventB
1910+
FROM
1911+
t1 t1a JOIN t2 t2a ON t2a.K1r = t1a.K1
1912+
LEFT JOIN
1913+
( t1 t1i LEFT JOIN t2 t2i ON t2i.K1r = t1i.K1)
1914+
ON (t1i.K1 = 1) AND
1915+
(((t2i.K1r = t1a.K1 AND t2i.rowTimestamp > t2a.rowTimestamp ) OR
1916+
(t2i.rowTimestamp = t2a.rowTimestamp AND t2i.K2 > t2a.K2))
1917+
OR (t2i.K2 IS NULL))
1918+
WHERE
1919+
t2a.K1r = 1 AND t2i.K2 IS NULL;
1920+
id select_type table type possible_keys key key_len ref rows filtered Extra
1921+
1 SIMPLE t1a const PRIMARY PRIMARY 4 const 1 100.00
1922+
1 SIMPLE t2a ALL NULL NULL NULL NULL 3 100.00 Using where
1923+
1 SIMPLE t1i const PRIMARY PRIMARY 4 const 1 100.00 Using index
1924+
1 SIMPLE t2i ALL NULL NULL NULL NULL 3 100.00 Using where; Not exists
1925+
Warnings:
1926+
Note 1003 select 1 AS `K1`,'T1Row1' AS `Name`,`test`.`t2a`.`K2` AS `K2`,`test`.`t2a`.`K1r` AS `K1r`,`test`.`t2a`.`rowTimestamp` AS `rowTimestamp`,`test`.`t2a`.`Event` AS `Event`,`test`.`t2i`.`K2` AS `K2B`,`test`.`t2i`.`K1r` AS `K1rB`,`test`.`t2i`.`rowTimestamp` AS `rowTimestampB`,`test`.`t2i`.`Event` AS `EventB` from `test`.`t1` `t1a` join `test`.`t2` `t2a` left join (`test`.`t1` `t1i` left join `test`.`t2` `t2i` on((`test`.`t2i`.`K1r` = 1))) on(((`test`.`t1i`.`K1` = 1) and (((`test`.`t2i`.`K1r` = 1) and (`test`.`t2i`.`rowTimestamp` > `test`.`t2a`.`rowTimestamp`)) or ((`test`.`t2i`.`rowTimestamp` = `test`.`t2a`.`rowTimestamp`) and (`test`.`t2i`.`K2` > `test`.`t2a`.`K2`)) or isnull(`test`.`t2i`.`K2`)))) where ((`test`.`t2a`.`K1r` = 1) and isnull(`test`.`t2i`.`K2`))
1927+
CREATE VIEW v1 AS
1928+
SELECT t2i.*
1929+
FROM t1 as t1i LEFT JOIN t2 as t2i ON t2i.K1r = t1i.K1
1930+
WHERE t1i.K1 = 1 ;
1931+
SELECT
1932+
t1a.*, t2a.*, t2b.K2 as K2B, t2b.K1r as K1rB,
1933+
t2b.rowTimestamp as rowTimestampB, t2b.Event as EventB
1934+
FROM
1935+
t1 as t1a JOIN t2 as t2a ON t2a.K1r = t1a.K1
1936+
LEFT JOIN
1937+
v1 as t2b
1938+
ON ((t2b.K1r = t1a.K1 AND t2b.rowTimestamp > t2a.rowTimestamp) OR
1939+
(t2b.rowTimestamp = t2a.rowTimestamp AND t2b.K2 > t2a.K2))
1940+
OR (t2b.K2 IS NULL)
1941+
WHERE
1942+
t1a.K1 = 1 AND
1943+
t2b.K2 IS NULL;
1944+
K1 Name K2 K1r rowTimestamp Event K2B K1rB rowTimestampB EventB
1945+
1 T1Row1 3 1 2015-04-13 10:42:12 T1Row1Event3 NULL NULL NULL NULL
1946+
EXPLAIN EXTENDED SELECT
1947+
t1a.*, t2a.*, t2b.K2 as K2B, t2b.K1r as K1rB,
1948+
t2b.rowTimestamp as rowTimestampB, t2b.Event as EventB
1949+
FROM
1950+
t1 as t1a JOIN t2 as t2a ON t2a.K1r = t1a.K1
1951+
LEFT JOIN
1952+
v1 as t2b
1953+
ON ((t2b.K1r = t1a.K1 AND t2b.rowTimestamp > t2a.rowTimestamp) OR
1954+
(t2b.rowTimestamp = t2a.rowTimestamp AND t2b.K2 > t2a.K2))
1955+
OR (t2b.K2 IS NULL)
1956+
WHERE
1957+
t1a.K1 = 1 AND
1958+
t2b.K2 IS NULL;
1959+
id select_type table type possible_keys key key_len ref rows filtered Extra
1960+
1 SIMPLE t1a const PRIMARY PRIMARY 4 const 1 100.00
1961+
1 SIMPLE t2a ALL NULL NULL NULL NULL 3 100.00 Using where
1962+
1 SIMPLE t1i const PRIMARY PRIMARY 4 const 1 100.00 Using index
1963+
1 SIMPLE t2i ALL NULL NULL NULL NULL 3 100.00 Using where; Not exists
1964+
Warnings:
1965+
Note 1003 select 1 AS `K1`,'T1Row1' AS `Name`,`t2a`.`K2` AS `K2`,`t2a`.`K1r` AS `K1r`,`t2a`.`rowTimestamp` AS `rowTimestamp`,`t2a`.`Event` AS `Event`,`test`.`t2i`.`K2` AS `K2B`,`test`.`t2i`.`K1r` AS `K1rB`,`test`.`t2i`.`rowTimestamp` AS `rowTimestampB`,`test`.`t2i`.`Event` AS `EventB` from `test`.`t1` `t1a` join `test`.`t2` `t2a` left join (`test`.`t1` `t1i` left join `test`.`t2` `t2i` on((`test`.`t2i`.`K1r` = 1))) on(((`test`.`t1i`.`K1` = 1) and (((`test`.`t2i`.`K1r` = 1) and (`test`.`t2i`.`rowTimestamp` > `t2a`.`rowTimestamp`)) or ((`test`.`t2i`.`rowTimestamp` = `t2a`.`rowTimestamp`) and (`test`.`t2i`.`K2` > `t2a`.`K2`)) or isnull(`test`.`t2i`.`K2`)))) where ((`t2a`.`K1r` = 1) and isnull(`test`.`t2i`.`K2`))
1966+
DROP VIEW v1;
1967+
DROP TABLE t1,t2;
18731968
set optimizer_search_depth= @tmp_mdev621;

mysql-test/r/join_nested_jcl6.result

Lines changed: 95 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1881,6 +1881,101 @@ f4
18811881
NULL
18821882
NULL
18831883
DROP TABLE t1,t2,t3,t4,t5;
1884+
#
1885+
# MDEV-7992: Nested left joins + 'not exists' optimization
1886+
#
1887+
CREATE TABLE t1(
1888+
K1 INT PRIMARY KEY,
1889+
Name VARCHAR(15)
1890+
);
1891+
INSERT INTO t1 VALUES
1892+
(1,'T1Row1'), (2,'T1Row2');
1893+
CREATE TABLE t2(
1894+
K2 INT PRIMARY KEY,
1895+
K1r INT,
1896+
rowTimestamp DATETIME,
1897+
Event VARCHAR(15)
1898+
);
1899+
INSERT INTO t2 VALUES
1900+
(1, 1, '2015-04-13 10:42:11' ,'T1Row1Event1'),
1901+
(2, 1, '2015-04-13 10:42:12' ,'T1Row1Event2'),
1902+
(3, 1, '2015-04-13 10:42:12' ,'T1Row1Event3');
1903+
SELECT t1a.*, t2a.*,
1904+
t2i.K2 AS K2B, t2i.K1r AS K1rB,
1905+
t2i.rowTimestamp AS rowTimestampB, t2i.Event AS EventB
1906+
FROM
1907+
t1 t1a JOIN t2 t2a ON t2a.K1r = t1a.K1
1908+
LEFT JOIN
1909+
( t1 t1i LEFT JOIN t2 t2i ON t2i.K1r = t1i.K1)
1910+
ON (t1i.K1 = 1) AND
1911+
(((t2i.K1r = t1a.K1 AND t2i.rowTimestamp > t2a.rowTimestamp ) OR
1912+
(t2i.rowTimestamp = t2a.rowTimestamp AND t2i.K2 > t2a.K2))
1913+
OR (t2i.K2 IS NULL))
1914+
WHERE
1915+
t2a.K1r = 1 AND t2i.K2 IS NULL;
1916+
K1 Name K2 K1r rowTimestamp Event K2B K1rB rowTimestampB EventB
1917+
1 T1Row1 3 1 2015-04-13 10:42:12 T1Row1Event3 NULL NULL NULL NULL
1918+
EXPLAIN EXTENDED SELECT t1a.*, t2a.*,
1919+
t2i.K2 AS K2B, t2i.K1r AS K1rB,
1920+
t2i.rowTimestamp AS rowTimestampB, t2i.Event AS EventB
1921+
FROM
1922+
t1 t1a JOIN t2 t2a ON t2a.K1r = t1a.K1
1923+
LEFT JOIN
1924+
( t1 t1i LEFT JOIN t2 t2i ON t2i.K1r = t1i.K1)
1925+
ON (t1i.K1 = 1) AND
1926+
(((t2i.K1r = t1a.K1 AND t2i.rowTimestamp > t2a.rowTimestamp ) OR
1927+
(t2i.rowTimestamp = t2a.rowTimestamp AND t2i.K2 > t2a.K2))
1928+
OR (t2i.K2 IS NULL))
1929+
WHERE
1930+
t2a.K1r = 1 AND t2i.K2 IS NULL;
1931+
id select_type table type possible_keys key key_len ref rows filtered Extra
1932+
1 SIMPLE t1a const PRIMARY PRIMARY 4 const 1 100.00
1933+
1 SIMPLE t2a ALL NULL NULL NULL NULL 3 100.00 Using where
1934+
1 SIMPLE t1i const PRIMARY PRIMARY 4 const 1 100.00 Using index
1935+
1 SIMPLE t2i ALL NULL NULL NULL NULL 3 100.00 Using where; Not exists
1936+
Warnings:
1937+
Note 1003 select 1 AS `K1`,'T1Row1' AS `Name`,`test`.`t2a`.`K2` AS `K2`,`test`.`t2a`.`K1r` AS `K1r`,`test`.`t2a`.`rowTimestamp` AS `rowTimestamp`,`test`.`t2a`.`Event` AS `Event`,`test`.`t2i`.`K2` AS `K2B`,`test`.`t2i`.`K1r` AS `K1rB`,`test`.`t2i`.`rowTimestamp` AS `rowTimestampB`,`test`.`t2i`.`Event` AS `EventB` from `test`.`t1` `t1a` join `test`.`t2` `t2a` left join (`test`.`t1` `t1i` left join `test`.`t2` `t2i` on((`test`.`t2i`.`K1r` = 1))) on(((`test`.`t1i`.`K1` = 1) and (((`test`.`t2i`.`K1r` = 1) and (`test`.`t2i`.`rowTimestamp` > `test`.`t2a`.`rowTimestamp`)) or ((`test`.`t2i`.`rowTimestamp` = `test`.`t2a`.`rowTimestamp`) and (`test`.`t2i`.`K2` > `test`.`t2a`.`K2`)) or isnull(`test`.`t2i`.`K2`)))) where ((`test`.`t2a`.`K1r` = 1) and isnull(`test`.`t2i`.`K2`))
1938+
CREATE VIEW v1 AS
1939+
SELECT t2i.*
1940+
FROM t1 as t1i LEFT JOIN t2 as t2i ON t2i.K1r = t1i.K1
1941+
WHERE t1i.K1 = 1 ;
1942+
SELECT
1943+
t1a.*, t2a.*, t2b.K2 as K2B, t2b.K1r as K1rB,
1944+
t2b.rowTimestamp as rowTimestampB, t2b.Event as EventB
1945+
FROM
1946+
t1 as t1a JOIN t2 as t2a ON t2a.K1r = t1a.K1
1947+
LEFT JOIN
1948+
v1 as t2b
1949+
ON ((t2b.K1r = t1a.K1 AND t2b.rowTimestamp > t2a.rowTimestamp) OR
1950+
(t2b.rowTimestamp = t2a.rowTimestamp AND t2b.K2 > t2a.K2))
1951+
OR (t2b.K2 IS NULL)
1952+
WHERE
1953+
t1a.K1 = 1 AND
1954+
t2b.K2 IS NULL;
1955+
K1 Name K2 K1r rowTimestamp Event K2B K1rB rowTimestampB EventB
1956+
1 T1Row1 3 1 2015-04-13 10:42:12 T1Row1Event3 NULL NULL NULL NULL
1957+
EXPLAIN EXTENDED SELECT
1958+
t1a.*, t2a.*, t2b.K2 as K2B, t2b.K1r as K1rB,
1959+
t2b.rowTimestamp as rowTimestampB, t2b.Event as EventB
1960+
FROM
1961+
t1 as t1a JOIN t2 as t2a ON t2a.K1r = t1a.K1
1962+
LEFT JOIN
1963+
v1 as t2b
1964+
ON ((t2b.K1r = t1a.K1 AND t2b.rowTimestamp > t2a.rowTimestamp) OR
1965+
(t2b.rowTimestamp = t2a.rowTimestamp AND t2b.K2 > t2a.K2))
1966+
OR (t2b.K2 IS NULL)
1967+
WHERE
1968+
t1a.K1 = 1 AND
1969+
t2b.K2 IS NULL;
1970+
id select_type table type possible_keys key key_len ref rows filtered Extra
1971+
1 SIMPLE t1a const PRIMARY PRIMARY 4 const 1 100.00
1972+
1 SIMPLE t2a ALL NULL NULL NULL NULL 3 100.00 Using where
1973+
1 SIMPLE t1i const PRIMARY PRIMARY 4 const 1 100.00 Using index
1974+
1 SIMPLE t2i ALL NULL NULL NULL NULL 3 100.00 Using where; Not exists
1975+
Warnings:
1976+
Note 1003 select 1 AS `K1`,'T1Row1' AS `Name`,`t2a`.`K2` AS `K2`,`t2a`.`K1r` AS `K1r`,`t2a`.`rowTimestamp` AS `rowTimestamp`,`t2a`.`Event` AS `Event`,`test`.`t2i`.`K2` AS `K2B`,`test`.`t2i`.`K1r` AS `K1rB`,`test`.`t2i`.`rowTimestamp` AS `rowTimestampB`,`test`.`t2i`.`Event` AS `EventB` from `test`.`t1` `t1a` join `test`.`t2` `t2a` left join (`test`.`t1` `t1i` left join `test`.`t2` `t2i` on((`test`.`t2i`.`K1r` = 1))) on(((`test`.`t1i`.`K1` = 1) and (((`test`.`t2i`.`K1r` = 1) and (`test`.`t2i`.`rowTimestamp` > `t2a`.`rowTimestamp`)) or ((`test`.`t2i`.`rowTimestamp` = `t2a`.`rowTimestamp`) and (`test`.`t2i`.`K2` > `t2a`.`K2`)) or isnull(`test`.`t2i`.`K2`)))) where ((`t2a`.`K1r` = 1) and isnull(`test`.`t2i`.`K2`))
1977+
DROP VIEW v1;
1978+
DROP TABLE t1,t2;
18841979
set optimizer_search_depth= @tmp_mdev621;
18851980
CREATE TABLE t5 (a int, b int, c int, PRIMARY KEY(a), KEY b_i (b));
18861981
CREATE TABLE t6 (a int, b int, c int, PRIMARY KEY(a), KEY b_i (b));

mysql-test/t/join_nested.test

Lines changed: 70 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1309,5 +1309,74 @@ LEFT JOIN t4 AS alias5
13091309
JOIN t5 ON alias5.f5
13101310
ON alias2.f3 ON alias1.f2;
13111311
DROP TABLE t1,t2,t3,t4,t5;
1312-
set optimizer_search_depth= @tmp_mdev621;
13131312

1313+
--echo #
1314+
--echo # MDEV-7992: Nested left joins + 'not exists' optimization
1315+
--echo #
1316+
1317+
CREATE TABLE t1(
1318+
K1 INT PRIMARY KEY,
1319+
Name VARCHAR(15)
1320+
);
1321+
1322+
INSERT INTO t1 VALUES
1323+
(1,'T1Row1'), (2,'T1Row2');
1324+
1325+
1326+
CREATE TABLE t2(
1327+
K2 INT PRIMARY KEY,
1328+
K1r INT,
1329+
rowTimestamp DATETIME,
1330+
Event VARCHAR(15)
1331+
);
1332+
1333+
INSERT INTO t2 VALUES
1334+
(1, 1, '2015-04-13 10:42:11' ,'T1Row1Event1'),
1335+
(2, 1, '2015-04-13 10:42:12' ,'T1Row1Event2'),
1336+
(3, 1, '2015-04-13 10:42:12' ,'T1Row1Event3');
1337+
1338+
let $q1=
1339+
SELECT t1a.*, t2a.*,
1340+
t2i.K2 AS K2B, t2i.K1r AS K1rB,
1341+
t2i.rowTimestamp AS rowTimestampB, t2i.Event AS EventB
1342+
FROM
1343+
t1 t1a JOIN t2 t2a ON t2a.K1r = t1a.K1
1344+
LEFT JOIN
1345+
( t1 t1i LEFT JOIN t2 t2i ON t2i.K1r = t1i.K1)
1346+
ON (t1i.K1 = 1) AND
1347+
(((t2i.K1r = t1a.K1 AND t2i.rowTimestamp > t2a.rowTimestamp ) OR
1348+
(t2i.rowTimestamp = t2a.rowTimestamp AND t2i.K2 > t2a.K2))
1349+
OR (t2i.K2 IS NULL))
1350+
WHERE
1351+
t2a.K1r = 1 AND t2i.K2 IS NULL;
1352+
1353+
eval $q1;
1354+
eval EXPLAIN EXTENDED $q1;
1355+
1356+
CREATE VIEW v1 AS
1357+
SELECT t2i.*
1358+
FROM t1 as t1i LEFT JOIN t2 as t2i ON t2i.K1r = t1i.K1
1359+
WHERE t1i.K1 = 1 ;
1360+
1361+
let $q2=
1362+
SELECT
1363+
t1a.*, t2a.*, t2b.K2 as K2B, t2b.K1r as K1rB,
1364+
t2b.rowTimestamp as rowTimestampB, t2b.Event as EventB
1365+
FROM
1366+
t1 as t1a JOIN t2 as t2a ON t2a.K1r = t1a.K1
1367+
LEFT JOIN
1368+
v1 as t2b
1369+
ON ((t2b.K1r = t1a.K1 AND t2b.rowTimestamp > t2a.rowTimestamp) OR
1370+
(t2b.rowTimestamp = t2a.rowTimestamp AND t2b.K2 > t2a.K2))
1371+
OR (t2b.K2 IS NULL)
1372+
WHERE
1373+
t1a.K1 = 1 AND
1374+
t2b.K2 IS NULL;
1375+
1376+
eval $q2;
1377+
eval EXPLAIN EXTENDED $q2;
1378+
1379+
DROP VIEW v1;
1380+
DROP TABLE t1,t2;
1381+
1382+
set optimizer_search_depth= @tmp_mdev621;

0 commit comments

Comments
 (0)