Skip to content

Commit

Permalink
opt: add transformation rule to convert anti join to left join
Browse files Browse the repository at this point in the history
Release justification: bug fixes and low-risk updates to new functionality

ConvertAntiToLeftJoin converts an anti join to a left join with the same
ON condition, wraps the expression in a Select to remove rows that matched
the ON condition, and then projects out the left side columns.
For example (assuming x is a not-null column in b):

  SELECT * FROM a WHERE NOT EXISTS (
    SELECT * FROM b WHERE ST_Intersects(a.geom, b.geom)
  );

is converted to:

  SELECT a.* FROM a LEFT JOIN b ON ST_Intersects(a.geom, b.geom)
  WHERE b.x IS NULL;

Note that this transformation is not desirable in the general case, but it
is useful if there is a possibility of creating an inverted join (such as in
the above example). For this reason, we only perform this transformation if
it is possible to generate an inverted join.

This transformation allows us to index-accelerate spatial anti joins, which
was not possible before.

Informs cockroachdb#53576

Release note (performance improvement): spatial anti joins can now
be index-accelerated, which can lead to performance improvements in some
cases.
  • Loading branch information
rytaft committed Sep 16, 2020
1 parent fbdf2d7 commit 4dc3206
Show file tree
Hide file tree
Showing 7 changed files with 445 additions and 50 deletions.
13 changes: 12 additions & 1 deletion pkg/sql/logictest/testdata/logic_test/inverted_join_geospatial
Original file line number Diff line number Diff line change
Expand Up @@ -303,7 +303,8 @@ SELECT lk, count(*), (SELECT count(*) FROM q) FROM (
5 2 4
6 1 4

# These queries perform anti-joins, which do not currently use an inverted join.
# Anti-join is supported by having the optimizer convert it to a left join,
# which is then converted to an inner join.
query I
SELECT lk FROM ltable WHERE NOT EXISTS (SELECT * FROM rtable WHERE ST_Intersects(ltable.geom2, rtable.geom))
ORDER BY lk
Expand All @@ -319,3 +320,13 @@ ORDER BY rk
12
14
15

query I
SELECT lk FROM ltable
WHERE NOT EXISTS (
SELECT * FROM rtable WHERE ST_Covers(ltable.geom2, rtable.geom) AND lk > 1 AND rk > 12
)
----
1
5
6
Original file line number Diff line number Diff line change
Expand Up @@ -107,12 +107,21 @@ SELECT count(*), (SELECT count(*) FROM q) FROM (
----
https://cockroachdb.github.io/distsqlplan/decode.html#eJyUlM9u2kAQxu99itGccLQq2EAOliqZpk5wRO3UGKVRipBjT4iLswu76ypRlHev_CehkEDDCe3M_Ga-nY_1E6pVjjaO3ZF7EkEhczgNg-9w7f68GA08H1rfvHE0_jEy4NKLhrCCwRhaTfVRXZvr-CYnuBy6oQv5An4VnU6XwDKgqUtEwXXryGCv5EukbrBqfl-y-YKBXDQ5GLmnEZwHng-yHhT4oPQs45qkokSr1urznMS9yZqC6mQYcBYGkwv4egX5YooMuUjJj-9JoX2NJk4ZLqVISCkhy9BTVeClD2h3GGZ8WegyPGWYCEloP6HOdE5oYy6SOAeVxBxuittbktBpd5BhSjrO8gp6ZigKvW6hdDwntM1n9vExHv9DUlN6LjJOsm1uTMD6qk551VnGU3pA9kq4D0u5tSLHYuD0DGQYFNoGp8sckzkW7lJqHaK0VBhSnJJsW--qXMrsPpaPyHAkxKJYwm-RcRDcBqe81htDnS4Dp79W22eOxZzuTrXdQ9S-tc9sdz9kX2_nmHX3gguZkqR0u-P_S97ROozVXeN_b3Oz0eOSbAi9s2EEwSRyw-qJIMOcbnXLsYwvMpvf6ZZjrtfY27nA_iELHMznkuaxFrLd3xRVuTnwr2Z-EM38yWjUjD8JJn40C4PLcas8hsRTkjaUf8rmzb98EMo3vzJ26jw-RGdIaim4og952ynXT-mcajuVKGRCF1Ik1Zj6GFRcFUhJ6Tpr1geP16lS4L-wuRe29sPWXri3AZvbcPcA2NqGe3vh_n7Z_b3w8RY8ff70NwAA__-fpxhU

# This query performs an anti-join, and does not currently use an inverted join.
# Anti joins are also converted to an inner join by the optimizer.
query T
SELECT url FROM [EXPLAIN (DISTSQL)
SELECT lk FROM ltable WHERE NOT EXISTS (SELECT * FROM rtable WHERE ST_Intersects(ltable.geom2, rtable.geom))]
----
https://cockroachdb.github.io/distsqlplan/decode.html#eJy0U9FumzAUfd9XWPcpmZwRTLIHP1FtVKXKoAtIq1ShicFVhkYws420Ksq_T-BoKWh0dFEfr-8595xjXx9A_SyBQ-RtvA8xaWRJrrfhJ_Lg3d9trvyAzD76URx93szJCVL-MIhSp99KJF9uvK1HgjAm3n2LJLMT7q2Byacwpb8WlUapMNNqZia826HYM3oCdtV8ngCFSuQYpHtUwB_ABgoMKDiQUKilyFApIdvWoQP6-S_gSwpFVTe6PU4oZEIi8APoQpcIHOJWYItpjtJaAoUcdVqU3Xhjxa1lsU_lI1CI6rRSnCysVjRsNCeuTV0HkiMF0eiziNLpDoHbRzrdSCAWorbWPQtjg1e9wfb0hPa0hBZbWM7_ZGTTrbCJVpzFKxtx-kbk2Kv_scFGPbBRD2fpphIyR4n58KX_DflLkJtUfb8VRYXSWvVzxI81crLxrmNyFcQ-uQ39oI0QDD6cyyhxnfn5kkfTOS9Z5y2qWlQKJ-3zso2G-Q7NVSnRyAzvpMg6GVOGHa87yFFp012bwq-6VrcCT8n2s-T3PfJySGaXKDuXkFcvILMhef0s2R5kTo5vfgcAAP__M3_rTA==
https://cockroachdb.github.io/distsqlplan/decode.html#eJyUk9Fum0wQhe__pxjNFf61qg22pQqpElFKGiIKKRA1UmRFBCYODdmlu0uVKPK7VwtWHdPYtS93OWfmm7PMK6qfNbqY-qF_mkErazhL4q9w419fhidBBNbnIM3Sb-EI1pL6sVfUOr-rCb6f-4kPUZyBf22UYK11__cy-Vam9G3FNUlFhVZWX-HDksSTw9bC7jQaLZAhFyVF-RMpdG_QxgXDRoqClBLSXL12gqB8RnfCsOJNq831gmEhJKH7irrSNaGLtSjyGlSRc7hr7-9JwmQ8QYYl6byqO9OKoWj1poTS-ZLQtVfs8DYB_0VSU3khKk5ybG91wH48z4x3W_GSnpH9cfjPjRxk4zkMvNkIGcatdsGbMs9mnoO7SJ1jSA1hQnlJcuy8S9nI6imXL8gwFOKxbeCHqDgI7oJnxoqjIe2UgTff0BpUZpjnO4GnxwD__YL2eHrQC852ttlUb7mQJUkqhxX_LXmH9TxXD-tfYLYdbvbSkAtJ8OU8g_gq8xO4iIMIGdZ0ry3PGX2S1fJBW55tkjyrak3ShAlB2i2Y2cQgOs36xTo9STMrugpDOEkhiLKPm_h3pz4_JvWEVCO4ooOCnpgsqFxSn60SrSzoUoqia9Mf487XXZSkdP_V7g8B7z8ZwLdme6_Z2W929ppnW2Z7aJ4eYXaG5tle83yAvVj99zsAAP__b1jKcw==

query T
SELECT url FROM [EXPLAIN (DISTSQL)
SELECT lk FROM ltable
WHERE NOT EXISTS (
SELECT * FROM rtable WHERE ST_Covers(ltable.geom1, rtable.geom) AND lk > 5 AND rk > 12
)]
----
https://cockroachdb.github.io/distsqlplan/decode.html#eJyUk29vmzAQxt_vU5zuFUzWEiCRJqRJRC1dqTLoEqpV6qKKwjVldTGzTdWq6nefDFn-rcmalz4_z92PB98Lqt8cfZyG4_AohUZyOJkk3-AqvDwfj6IYrONomk6_j21YSPh9p-A6u-EEP07DSQhxkkJ4aZRgLXQfO5lcl1lKX-fikaSyOvunOYkHhy1U7cmGUXwMFr-Hn02_7xEM7UVJLkuOa9szZFiJguLsgRT6V-jgjGEtRU5KCWlKL60gKp7Q7zMsq7rRpjxjmAtJ6L-gLjUn9JGLPOOg8qyCm-b2liT0e31kWJDOSt62Pym5JulD4CzBfN-P4vQzzl4Zikav2iudzQl955W9HyGqHklqKs5EWZHsOZvTu4ACE9B1WRX0hGzpCJ9qCatkA5dBMLCRYRJD4K0y-4vLMGm0D4HHAocF7k589xB8gz2hrCDZc99Er2X5kMlnZDgW4r6p4ZcoKxCVSbRjXfsEj0EwtJekBpMZ3uFOWO8Q2H9_t9PzNqh3jRnsHLPq3lRCFiSp2O74f8kbrKeZulu8icFmsOlzTT5Moq-nKSQXaTiBsySKkSGnW20Frv1FlvM7bQWOSXLt_UbTdmHNZkfxUdot6tFomlrxxXgMoymYd7KKf3fqw0NSn5CqRaXoXUH3TRZUzKnLVolG5nQuRd6O6Y5J62sLBSnd3TrdIaq6KwO4bnb2mt39ZnevebBhdrbN3gFmd9s82GsebmHPXj_8CQAA___Yjtw0

# Bounding box operations.
statement ok
Expand Down
Loading

0 comments on commit 4dc3206

Please sign in to comment.