Skip to content

Commit

Permalink
Fix handling of joins with filter containing correlated joins
Browse files Browse the repository at this point in the history
In a query like:

    SELECT
        n.nspname AS schema,
        t.typname AS typename,
        t.oid::int4 AS typeid
    FROM
        pg_type t
        LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace
    WHERE
        EXISTS (SELECT 1 FROM pg_catalog.pg_type el WHERE el.oid = t.typelem);

The filter `EXISTS (SELECT 1 FROM pg_catalog.pg_type el WHERE el.oid =
t.typelem)` was placed in-between correlated-join and join:

    └ CorrelatedJoin[typname, oid, typnamespace, typelem, nspname, oid, (SELECT 1 FROM (el))] (rows=0)
      └ Filter[EXISTS (SELECT 1 FROM (el))] (rows=0)
        └ NestedLoopJoin[LEFT | (oid = typnamespace)] (rows=unknown)

Given that the filter uses the output of the `CorrelatedJoin`, that led
to an error:

    Couldn't create execution plan from logical plan because of: Couldn't find (SELECT 1 FROM (el)) in SourceSymbols

The filter must be placed above the correlated join, not below.

Fixes #14671
  • Loading branch information
mfussenegger committed Oct 23, 2023
1 parent 58c216b commit 5c869de
Show file tree
Hide file tree
Showing 3 changed files with 35 additions and 1 deletion.
15 changes: 15 additions & 0 deletions docs/appendices/release-notes/5.4.5.rst
Original file line number Diff line number Diff line change
Expand Up @@ -46,6 +46,21 @@ See the :ref:`version_5.4.0` release notes for a full list of changes in the
Fixes
=====

- Fixed an issue that led to ``Couldn't create execution plan from logical plan
..`` errors when trying to use a correlated join in the ``WHERE`` clause of a
query with a join. For example::

SELECT
n.nspname AS schema,
t.typname AS typename,
t.oid::int4 AS typeid
FROM
pg_type t
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace
WHERE
EXISTS (
SELECT 1 FROM pg_catalog.pg_type el WHERE el.oid = t.typelem);

- Fixed an issue that prevented namespaces from showing up in
``pg_catalog.pg_namespace`` if a user had privileges on a table within a
schema, but no privileges on the schema itself.
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -142,11 +142,11 @@ static LogicalPlan buildJoinTree(List<AnalyzedRelation> from,
);
joinNames.add(nextRel.relationName());
}
joinPlan = subQueries.applyCorrelatedJoin(joinPlan);
if (!queryParts.isEmpty()) {
joinPlan = Filter.create(joinPlan, AndOperator.join(queryParts.values()));
queryParts.clear();
}
joinPlan = subQueries.applyCorrelatedJoin(joinPlan);
joinPlan = Filter.create(joinPlan, AndOperator.join(correlatedSubQueriesFromJoin.correlatedSubQueries()));
joinPlan = Filter.create(joinPlan, AndOperator.join(correlatedSubQueriesFromWhereClause.correlatedSubQueries()));
assert joinPairsByRelations.isEmpty() : "Must've applied all joinPairs";
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -429,4 +429,23 @@ public void test_can_use_column_in_query_paired_with_correlation_that_is_not_sel
assertThat(result.getInt(1)).isEqualTo(1);
}
}

@Test
public void test_correlated_subquery_together_with_join() throws Exception {
// https://github.com/crate/crate/issues/14671
execute(
"""
SELECT
n.nspname AS schema,
t.typname AS typename,
t.oid::int4 AS typeid
FROM
pg_type t
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace
WHERE
EXISTS (
SELECT 1 FROM pg_catalog.pg_type el WHERE el.oid = t.typelem);
""");
assertThat(response).hasRowCount(24L);
}
}

0 comments on commit 5c869de

Please sign in to comment.