Do not move to prewhere in select with joins

This commit is contained in:
vdimir 2023-01-18 12:17:30 +00:00
parent 35431e91e3
commit b76779797a
No known key found for this signature in database
GPG Key ID: 6EE4CE2BEDC51862
3 changed files with 85 additions and 1 deletions

View File

@ -560,7 +560,10 @@ InterpreterSelectQuery::InterpreterSelectQuery(
view = nullptr; view = nullptr;
} }
if (try_move_to_prewhere && storage && storage->canMoveConditionsToPrewhere() && query.where() && !query.prewhere()) if (try_move_to_prewhere
&& storage && storage->canMoveConditionsToPrewhere()
&& query.where() && !query.prewhere()
&& !query.hasJoin()) /// Join may produce rows with nulls or default values, it's difficult to analyze if they affected or not.
{ {
/// PREWHERE optimization: transfer some condition from WHERE to PREWHERE if enabled and viable /// PREWHERE optimization: transfer some condition from WHERE to PREWHERE if enabled and viable
if (const auto & column_sizes = storage->getColumnSizes(); !column_sizes.empty()) if (const auto & column_sizes = storage->getColumnSizes(); !column_sizes.empty())

View File

@ -0,0 +1,38 @@
-- { echoOn }
SELECT * FROM test1 LEFT JOIN test2 ON test1.col1 = test2.col1
WHERE test2.col1 IS NULL
ORDER BY test2.col1
;
12321 -30 \N \N
SELECT * FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NULL
ORDER BY test2.col1
;
\N \N 12321 -30
SELECT * FROM test1 LEFT JOIN test2 ON test1.col1 = test2.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
123 123 123 5600
321 -32 321 5601
SELECT * FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
123 5600 123 123
321 5601 321 -32
SELECT test2.col1, test1.* FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
123 123 123
321 321 -32
SELECT test2.col3, test1.* FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
5600 123 123
5601 321 -32
DROP TABLE IF EXISTS test1;
DROP TABLE IF EXISTS test2;

View File

@ -0,0 +1,43 @@
CREATE OR REPLACE TABLE test1 ( `col1` UInt64, `col2` Int8 ) ENGINE = MergeTree ORDER BY col1;
CREATE OR REPLACE TABLE test2 ( `col1` UInt64, `col3` Int16 ) ENGINE = MergeTree ORDER BY col1;
INSERT INTO test1 VALUES (123, 123), (12321, -30), (321, -32);
INSERT INTO test2 VALUES (123, 5600), (321, 5601);
SET join_use_nulls = 1;
-- { echoOn }
SELECT * FROM test1 LEFT JOIN test2 ON test1.col1 = test2.col1
WHERE test2.col1 IS NULL
ORDER BY test2.col1
;
SELECT * FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NULL
ORDER BY test2.col1
;
SELECT * FROM test1 LEFT JOIN test2 ON test1.col1 = test2.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
SELECT * FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
SELECT test2.col1, test1.* FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
SELECT test2.col3, test1.* FROM test2 RIGHT JOIN test1 ON test2.col1 = test1.col1
WHERE test2.col1 IS NOT NULL
ORDER BY test2.col1
;
DROP TABLE IF EXISTS test1;
DROP TABLE IF EXISTS test2;