Skip to content

Commit 033ddf0

Browse files
authored
fix(optimizer): convert INNER JOINs to LEFT JOINs when merging LEFT JOIN subqueries (#5980)
* fix(optimizer): convert INNER JOINs to LEFT JOINs when merging LEFT JOIN subqueries * change comment * refactor names
1 parent 51b1bb1 commit 033ddf0

File tree

2 files changed

+90
-0
lines changed

2 files changed

+90
-0
lines changed

sqlglot/optimizer/merge_subqueries.py

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -282,7 +282,14 @@ def _merge_joins(outer_scope: Scope, inner_scope: Scope, from_or_join: FromOrJoi
282282
new_joins = []
283283

284284
joins = inner_scope.expression.args.get("joins") or []
285+
286+
outer_is_left_join = isinstance(from_or_join, exp.Join) and from_or_join.side == "LEFT"
287+
285288
for join in joins:
289+
if outer_is_left_join and not join.method and join.kind in ("", "INNER"):
290+
join.args.pop("kind", None)
291+
join.set("side", "LEFT")
292+
286293
new_joins.append(join)
287294
outer_scope.add_source(join.alias_or_name, inner_scope.sources[join.alias_or_name])
288295

tests/fixtures/optimizer/merge_subqueries.sql

Lines changed: 83 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -511,3 +511,86 @@ with cte as (
511511
)
512512
select cte.mult from cte;
513513
SELECT x.a * x.b AS mult FROM x AS x;
514+
515+
# title: replace INNER JOIN with LEFT JOIN when it exists in a subquery used as the RHS of a LEFT JOIN
516+
WITH
517+
t0 AS (
518+
SELECT 5 as id
519+
),
520+
t1 AS (
521+
SELECT 1 AS id, 'US' AS cid
522+
),
523+
t2 AS (
524+
SELECT 1 AS id, 'US' AS cid
525+
)
526+
SELECT
527+
t0.id,
528+
t3.cid AS cid
529+
FROM t0
530+
LEFT JOIN (
531+
SELECT
532+
t1.id,
533+
t2.cid
534+
FROM t1
535+
INNER JOIN t2
536+
ON t1.cid = t2.cid
537+
) AS t3
538+
ON t0.id = t3.id;
539+
WITH t0 AS (SELECT 5 AS id), t1 AS (SELECT 1 AS id, 'US' AS cid), t2 AS (SELECT 1 AS id, 'US' AS cid) SELECT t0.id AS id, t2.cid AS cid FROM t0 AS t0 LEFT JOIN t1 AS t1 ON t0.id = t1.id LEFT JOIN t2 AS t2 ON t1.cid = t2.cid;
540+
541+
# title: preserve INNER JOIN when it exists in a subquery used as the RHS of a RIGHT JOIN
542+
WITH
543+
t0 AS (
544+
SELECT 5 as id
545+
),
546+
t1 AS (
547+
SELECT 1 AS id, 'US' AS cid
548+
),
549+
t2 AS (
550+
SELECT 1 AS id, 'US' AS cid
551+
)
552+
SELECT
553+
t0.id,
554+
t3.cid AS cid
555+
FROM t0
556+
RIGHT JOIN (
557+
SELECT
558+
t1.id,
559+
t2.cid
560+
FROM t1
561+
INNER JOIN t2
562+
ON t1.cid = t2.cid
563+
) AS t3
564+
ON t0.id = t3.id;
565+
WITH t0 AS (SELECT 5 AS id), t1 AS (SELECT 1 AS id, 'US' AS cid), t2 AS (SELECT 1 AS id, 'US' AS cid) SELECT t0.id AS id, t2.cid AS cid FROM t0 AS t0 RIGHT JOIN t1 AS t1 ON t0.id = t1.id INNER JOIN t2 AS t2 ON t1.cid = t2.cid;
566+
567+
# title: replace multiple INNER JOINS with LEFT JOINS when they exist in a subquery used as the RHS of a LEFT JOIN
568+
WITH
569+
t0 AS (
570+
SELECT 5 as id
571+
),
572+
t1 AS (
573+
SELECT 1 AS id, 'US' AS cid
574+
),
575+
t2 AS (
576+
SELECT 1 AS id, 'US' AS cid
577+
),
578+
t3 AS (
579+
SELECT 1 AS id, 'CA' AS cid
580+
)
581+
SELECT
582+
t0.id,
583+
t4.cid AS cid
584+
FROM t0
585+
LEFT JOIN (
586+
SELECT
587+
t1.id,
588+
t3.cid
589+
FROM t1
590+
INNER JOIN t2
591+
ON t1.cid = t2.cid
592+
INNER JOIN t3
593+
ON t2.id = t3.id
594+
) AS t4
595+
ON t0.id = t4.id;
596+
WITH t0 AS (SELECT 5 AS id), t1 AS (SELECT 1 AS id, 'US' AS cid), t2 AS (SELECT 1 AS id, 'US' AS cid), t3 AS (SELECT 1 AS id, 'CA' AS cid) SELECT t0.id AS id, t3.cid AS cid FROM t0 AS t0 LEFT JOIN t1 AS t1 ON t0.id = t1.id LEFT JOIN t2 AS t2 ON t1.cid = t2.cid LEFT JOIN t3 AS t3 ON t2.id = t3.id;

0 commit comments

Comments
 (0)