diff --git a/src/backend/distributed/planner/distributed_planner.c b/src/backend/distributed/planner/distributed_planner.c index 99026972a..be046bf9b 100644 --- a/src/backend/distributed/planner/distributed_planner.c +++ b/src/backend/distributed/planner/distributed_planner.c @@ -249,13 +249,6 @@ distributed_planner(Query *parse, planContext.plannerRestrictionContext = CreateAndPushPlannerRestrictionContext( &fastPathContext); - /* - * Set RLS flag from the query. This is used to optimize equivalence class - * processing by skipping expensive RLS-specific merging for non-RLS queries. - */ - planContext.plannerRestrictionContext->relationRestrictionContext->hasRowSecurity = - parse->hasRowSecurity; - /* * We keep track of how many times we've recursed into the planner, primarily * to detect whether we are in a function call. We need to make sure that the @@ -2455,9 +2448,6 @@ CreateAndPushPlannerRestrictionContext( /* we'll apply logical AND as we add tables */ plannerRestrictionContext->relationRestrictionContext->allReferenceTables = true; - /* hasRowSecurity will be set later once we have the Query object */ - plannerRestrictionContext->relationRestrictionContext->hasRowSecurity = false; - plannerRestrictionContextList = lcons(plannerRestrictionContext, plannerRestrictionContextList); @@ -2545,9 +2535,6 @@ ResetPlannerRestrictionContext(PlannerRestrictionContext *plannerRestrictionCont /* we'll apply logical AND as we add tables */ plannerRestrictionContext->relationRestrictionContext->allReferenceTables = true; - - /* hasRowSecurity defaults to false, will be set by caller if needed */ - plannerRestrictionContext->relationRestrictionContext->hasRowSecurity = false; } diff --git a/src/backend/distributed/planner/multi_router_planner.c b/src/backend/distributed/planner/multi_router_planner.c index 84eb72825..14ce199c8 100644 --- a/src/backend/distributed/planner/multi_router_planner.c +++ b/src/backend/distributed/planner/multi_router_planner.c @@ -4200,7 +4200,6 @@ CopyRelationRestrictionContext(RelationRestrictionContext *oldContext) ListCell *relationRestrictionCell = NULL; newContext->allReferenceTables = oldContext->allReferenceTables; - newContext->hasRowSecurity = oldContext->hasRowSecurity; newContext->relationRestrictionList = NIL; foreach(relationRestrictionCell, oldContext->relationRestrictionList) diff --git a/src/backend/distributed/planner/relation_restriction_equivalence.c b/src/backend/distributed/planner/relation_restriction_equivalence.c index 0b475fbef..5b8ca7001 100644 --- a/src/backend/distributed/planner/relation_restriction_equivalence.c +++ b/src/backend/distributed/planner/relation_restriction_equivalence.c @@ -850,19 +850,22 @@ GenerateAttributeEquivalencesForRelationRestrictions(RelationRestrictionContext * This builds the standard attribute equivalence list. * * Skip RLS pattern detection entirely if the query doesn't - * use Row Level Security. The hasRowSecurity flag is set during query planning - * when any table has RLS policies active. This allows us to skip both the pattern - * detection loop AND the expensive merge pass for non-RLS queries (common case). + * use Row Level Security. The hasRowSecurity flag is checked from the query's + * parse tree when any table has RLS policies active. This allows us to skip + * both the pattern detection loop AND the expensive merge pass for non-RLS + * queries (common case). * * For RLS queries, detect patterns efficiently. We only need * to find one EC with both Var + non-Var members to justify the merge pass. * Once found, skip further pattern checks and focus on building equivalences. */ - bool skipRLSProcessing = !restrictionContext->hasRowSecurity; + bool skipRLSProcessing = true; foreach(relationRestrictionCell, restrictionContext->relationRestrictionList) { RelationRestriction *relationRestriction = (RelationRestriction *) lfirst(relationRestrictionCell); + + skipRLSProcessing = !relationRestriction->plannerInfo->parse->hasRowSecurity; List *equivalenceClasses = relationRestriction->plannerInfo->eq_classes; ListCell *equivalenceClassCell = NULL; @@ -890,8 +893,13 @@ GenerateAttributeEquivalencesForRelationRestrictions(RelationRestrictionContext { hasVar = true; } - else if (!IsA(expr, Param) && !IsA(expr, Const)) + else if (member->em_is_const && + !IsA(expr, Param) && !IsA(expr, Const)) { + /* + * Found a pseudoconstant expression (no Vars) that's not a + * Param or Const - this is the RLS function pattern. + */ hasNonVar = true; } @@ -1007,10 +1015,10 @@ MergeEquivalenceClassesWithSameFunctions(RelationRestrictionContext *restriction { hasVar = true; } - else if (!IsA(expr, Param) && !IsA(expr, Const)) + else if (member->em_is_const && !IsA(expr, Param) && !IsA(expr, Const)) { /* - * Found a non-Var expression (potential RLS function). + * Found a pseudoconstant expression (no Vars) - potential RLS function. * After stripping, this is typically a FUNCEXPR like * current_setting('session.current_tenant_id'). */ @@ -1123,37 +1131,49 @@ MergeEquivalenceClassesWithSameFunctions(RelationRestrictionContext *restriction mergedClass->equivalentAttributes = NIL; /* - * Build a PlannerInfo lookup map for quick access. - * Map varno → RelationRestriction for fast lookups. + * Match each Var to its RelationRestriction by comparing varno to + * the restriction's index field (which is the RTE index). */ ListCell *varCell = NULL; foreach(varCell, group->varsInTheseECs) { Var *var = (Var *) lfirst(varCell); ListCell *relResCell = NULL; + bool foundMatch = false; /* - * Find the appropriate RelationRestriction for this Var. - * We need the correct PlannerInfo context to process the Var. + * Find the RelationRestriction that corresponds to this Var. + * The index field contains the RTE index (varno) of the relation. */ foreach(relResCell, restrictionContext->relationRestrictionList) { RelationRestriction *relRestriction = (RelationRestriction *) lfirst(relResCell); - PlannerInfo *root = relRestriction->plannerInfo; - /* Check if this Var belongs to this planner's range table */ - if (var->varno < root->simple_rel_array_size && - root->simple_rte_array[var->varno] != NULL) + /* Direct match: varno equals the restriction's index */ + if (var->varno == relRestriction->index) { /* * Process this Var through AddToAttributeEquivalenceClass. * This handles subqueries, UNION ALL, LATERAL joins, etc. */ - AddToAttributeEquivalenceClass(mergedClass, root, var); - break; /* Found the right planner, move to next Var */ + AddToAttributeEquivalenceClass(mergedClass, + relRestriction->plannerInfo, var); + foundMatch = true; + break; } } + + /* + * If we didn't find a matching restriction, this Var might be from + * a context not tracked in our restriction list (e.g., subquery). + * We skip it as we only care about Vars from distributed tables. + */ + if (!foundMatch) + { + elog(DEBUG2, "Skipping Var with varno=%d in RLS merge - " + "no matching RelationRestriction found", var->varno); + } } /* Only emit if we successfully merged attributes from multiple sources */ @@ -2704,10 +2724,6 @@ FilterRelationRestrictionContext(RelationRestrictionContext *relationRestriction RelationRestrictionContext *filteredRestrictionContext = palloc0(sizeof(RelationRestrictionContext)); - /* Preserve RLS flag from the original context */ - filteredRestrictionContext->hasRowSecurity = - relationRestrictionContext->hasRowSecurity; - ListCell *relationRestrictionCell = NULL; foreach(relationRestrictionCell, relationRestrictionContext->relationRestrictionList) diff --git a/src/include/distributed/distributed_planner.h b/src/include/distributed/distributed_planner.h index e36651317..67637cd78 100644 --- a/src/include/distributed/distributed_planner.h +++ b/src/include/distributed/distributed_planner.h @@ -48,13 +48,6 @@ typedef enum RouterPlanType typedef struct RelationRestrictionContext { bool allReferenceTables; - - /* - * Set to true when any table in the query - * has Row Level Security policies active. - */ - bool hasRowSecurity; - List *relationRestrictionList; } RelationRestrictionContext; diff --git a/src/test/regress/expected/multi_rls_join_distribution_key.out b/src/test/regress/expected/multi_rls_join_distribution_key.out index cd8a39f0e..6d645e8a3 100644 --- a/src/test/regress/expected/multi_rls_join_distribution_key.out +++ b/src/test/regress/expected/multi_rls_join_distribution_key.out @@ -21,6 +21,8 @@ SET search_path TO rls_join_test; -- Create and distribute tables CREATE TABLE table_a (tenant_id uuid, id int); CREATE TABLE table_b (tenant_id uuid, id int); +CREATE TABLE table_c (tenant_id uuid, id int); +CREATE TABLE table_d (tenant_id uuid, id int); SELECT create_distributed_table('table_a', 'tenant_id'); create_distributed_table --------------------------------------------------------------------- @@ -33,6 +35,18 @@ SELECT create_distributed_table('table_b', 'tenant_id', colocate_with => 'table_ (1 row) +SELECT create_distributed_table('table_c', 'tenant_id', colocate_with => 'table_a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('table_d', 'tenant_id', colocate_with => 'table_a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + -- Grant privileges on tables GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA rls_join_test TO app_user; -- Insert test data @@ -42,9 +56,18 @@ INSERT INTO table_a VALUES INSERT INTO table_b VALUES ('0194d116-5dd5-74af-be74-7f5e8468eeb7', 10), ('0194d116-5dd5-74af-be74-7f5e8468eeb8', 20); --- Enable RLS and create policy +INSERT INTO table_c VALUES + ('0194d116-5dd5-74af-be74-7f5e8468eeb7', 100), + ('0194d116-5dd5-74af-be74-7f5e8468eeb8', 200); +INSERT INTO table_d VALUES + ('0194d116-5dd5-74af-be74-7f5e8468eeb7', 1000), + ('0194d116-5dd5-74af-be74-7f5e8468eeb8', 2000); +-- Enable RLS and create policies on multiple tables ALTER TABLE table_a ENABLE ROW LEVEL SECURITY; -CREATE POLICY tenant_isolation_0 ON table_a TO app_user +CREATE POLICY tenant_isolation_a ON table_a TO app_user + USING (tenant_id = current_setting('session.current_tenant_id')::UUID); +ALTER TABLE table_c ENABLE ROW LEVEL SECURITY; +CREATE POLICY tenant_isolation_c ON table_c TO app_user USING (tenant_id = current_setting('session.current_tenant_id')::UUID); -- Test scenario that previously failed -- Switch to app_user and execute the query with RLS @@ -59,22 +82,211 @@ BEGIN EXECUTE 'SET LOCAL session.current_tenant_id = ' || quote_literal(current_setting('application_name', true)); END; $$; --- This query should work with RLS enabled -SELECT c.id, t.id -FROM table_a AS c -LEFT OUTER JOIN table_b AS t ON c.tenant_id = t.tenant_id -ORDER BY c.id, t.id; +-- Simple 2-way join (original test case) +SELECT a.id, b.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +ORDER BY a.id, b.id; id | id --------------------------------------------------------------------- 1 | 10 (1 row) +SELECT a.id, b.id +FROM table_a AS a +RIGHT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +ORDER BY a.id, b.id; + id | id +--------------------------------------------------------------------- + 1 | 10 + | 20 +(2 rows) + +-- 3-way join with RLS on multiple tables +SELECT a.id, b.id, c.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +JOIN table_c AS c ON b.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 +(1 row) + +SELECT a.id, b.id, c.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_c AS c ON b.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 +(1 row) + +SELECT a.id, b.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 1000 +(1 row) + +SELECT a.id, b.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 1000 +(1 row) + +SELECT a.id, b.id, d.id +FROM table_a AS a +RIGHT JOIN table_b AS b ON a.tenant_id = b.tenant_id +RIGHT OUTER JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 1000 + | 20 | 2000 +(2 rows) + +SELECT a.id, b.id, d.id +FROM table_a AS a +RIGHT JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 1000 + | 20 | 2000 +(2 rows) + +SELECT a.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_c AS c ON a.tenant_id = c.tenant_id +JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, c.id, d.id; + id | id | id +--------------------------------------------------------------------- + 1 | 100 | 1000 +(1 row) + +SELECT a.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_c AS c ON a.tenant_id = c.tenant_id +LEFT OUTER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, c.id, d.id; + id | id | id +--------------------------------------------------------------------- + 1 | 100 | 1000 +(1 row) + +-- 4-way join with different join types +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +INNER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT JOIN table_c AS c ON b.tenant_id = c.tenant_id +INNER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + id | id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 | 1000 +(1 row) + +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +INNER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT JOIN table_c AS c ON b.tenant_id = c.tenant_id +RIGHT JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + id | id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 | 1000 + | | | 2000 +(2 rows) + +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_c AS c ON b.tenant_id = c.tenant_id +LEFT OUTER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + id | id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 | 1000 +(1 row) + +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +RIGHT OUTER JOIN table_c AS c ON b.tenant_id = c.tenant_id +LEFT OUTER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + id | id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 | 1000 +(1 row) + +-- IN subquery that can be transformed to semi-join +SELECT a.id +FROM table_a a +WHERE a.tenant_id IN ( + SELECT b.tenant_id + FROM table_b b + JOIN table_c c USING (tenant_id) +) +ORDER BY a.id; + id +--------------------------------------------------------------------- + 1 +(1 row) + +SELECT a.id +FROM table_a a +WHERE a.tenant_id IN ( + SELECT b.tenant_id + FROM table_b b + LEFT OUTER JOIN table_c c USING (tenant_id) +) +ORDER BY a.id; + id +--------------------------------------------------------------------- + 1 +(1 row) + +-- Another multi-way join variation +SELECT a.id, b.id, c.id +FROM table_a AS a +INNER JOIN table_b AS b ON a.tenant_id = b.tenant_id +INNER JOIN table_c AS c ON a.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 +(1 row) + +SELECT a.id, b.id, c.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_c AS c ON a.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + id | id | id +--------------------------------------------------------------------- + 1 | 10 | 100 +(1 row) + ROLLBACK; -- Switch back to superuser for cleanup RESET ROLE; -- Cleanup: Drop schema and all objects DROP SCHEMA rls_join_test CASCADE; -NOTICE: drop cascades to 2 other objects +NOTICE: drop cascades to 4 other objects DETAIL: drop cascades to table table_a drop cascades to table table_b +drop cascades to table table_c +drop cascades to table table_d DROP USER IF EXISTS app_user; diff --git a/src/test/regress/sql/multi_rls_join_distribution_key.sql b/src/test/regress/sql/multi_rls_join_distribution_key.sql index 363fad7a0..66f6afd1b 100644 --- a/src/test/regress/sql/multi_rls_join_distribution_key.sql +++ b/src/test/regress/sql/multi_rls_join_distribution_key.sql @@ -26,9 +26,13 @@ SET search_path TO rls_join_test; -- Create and distribute tables CREATE TABLE table_a (tenant_id uuid, id int); CREATE TABLE table_b (tenant_id uuid, id int); +CREATE TABLE table_c (tenant_id uuid, id int); +CREATE TABLE table_d (tenant_id uuid, id int); SELECT create_distributed_table('table_a', 'tenant_id'); SELECT create_distributed_table('table_b', 'tenant_id', colocate_with => 'table_a'); +SELECT create_distributed_table('table_c', 'tenant_id', colocate_with => 'table_a'); +SELECT create_distributed_table('table_d', 'tenant_id', colocate_with => 'table_a'); -- Grant privileges on tables GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA rls_join_test TO app_user; @@ -42,9 +46,21 @@ INSERT INTO table_b VALUES ('0194d116-5dd5-74af-be74-7f5e8468eeb7', 10), ('0194d116-5dd5-74af-be74-7f5e8468eeb8', 20); --- Enable RLS and create policy +INSERT INTO table_c VALUES + ('0194d116-5dd5-74af-be74-7f5e8468eeb7', 100), + ('0194d116-5dd5-74af-be74-7f5e8468eeb8', 200); + +INSERT INTO table_d VALUES + ('0194d116-5dd5-74af-be74-7f5e8468eeb7', 1000), + ('0194d116-5dd5-74af-be74-7f5e8468eeb8', 2000); + +-- Enable RLS and create policies on multiple tables ALTER TABLE table_a ENABLE ROW LEVEL SECURITY; -CREATE POLICY tenant_isolation_0 ON table_a TO app_user +CREATE POLICY tenant_isolation_a ON table_a TO app_user + USING (tenant_id = current_setting('session.current_tenant_id')::UUID); + +ALTER TABLE table_c ENABLE ROW LEVEL SECURITY; +CREATE POLICY tenant_isolation_c ON table_c TO app_user USING (tenant_id = current_setting('session.current_tenant_id')::UUID); -- Test scenario that previously failed @@ -63,12 +79,126 @@ BEGIN END; $$; --- This query should work with RLS enabled +-- Simple 2-way join (original test case) +SELECT a.id, b.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +ORDER BY a.id, b.id; -SELECT c.id, t.id -FROM table_a AS c -LEFT OUTER JOIN table_b AS t ON c.tenant_id = t.tenant_id -ORDER BY c.id, t.id; +SELECT a.id, b.id +FROM table_a AS a +RIGHT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +ORDER BY a.id, b.id; + +-- 3-way join with RLS on multiple tables +SELECT a.id, b.id, c.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +JOIN table_c AS c ON b.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + +SELECT a.id, b.id, c.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_c AS c ON b.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + +SELECT a.id, b.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + +SELECT a.id, b.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + +SELECT a.id, b.id, d.id +FROM table_a AS a +RIGHT JOIN table_b AS b ON a.tenant_id = b.tenant_id +RIGHT OUTER JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + +SELECT a.id, b.id, d.id +FROM table_a AS a +RIGHT JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_d AS d ON b.tenant_id = d.tenant_id +ORDER BY a.id, b.id, d.id; + +SELECT a.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_c AS c ON a.tenant_id = c.tenant_id +JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, c.id, d.id; + +SELECT a.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_c AS c ON a.tenant_id = c.tenant_id +LEFT OUTER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, c.id, d.id; + +-- 4-way join with different join types +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +INNER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT JOIN table_c AS c ON b.tenant_id = c.tenant_id +INNER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +INNER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT JOIN table_c AS c ON b.tenant_id = c.tenant_id +RIGHT JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_c AS c ON b.tenant_id = c.tenant_id +LEFT OUTER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + +SELECT a.id, b.id, c.id, d.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +RIGHT OUTER JOIN table_c AS c ON b.tenant_id = c.tenant_id +LEFT OUTER JOIN table_d AS d ON c.tenant_id = d.tenant_id +ORDER BY a.id, b.id, c.id, d.id; + +-- IN subquery that can be transformed to semi-join +SELECT a.id +FROM table_a a +WHERE a.tenant_id IN ( + SELECT b.tenant_id + FROM table_b b + JOIN table_c c USING (tenant_id) +) +ORDER BY a.id; + +SELECT a.id +FROM table_a a +WHERE a.tenant_id IN ( + SELECT b.tenant_id + FROM table_b b + LEFT OUTER JOIN table_c c USING (tenant_id) +) +ORDER BY a.id; + +-- Another multi-way join variation +SELECT a.id, b.id, c.id +FROM table_a AS a +INNER JOIN table_b AS b ON a.tenant_id = b.tenant_id +INNER JOIN table_c AS c ON a.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; + +SELECT a.id, b.id, c.id +FROM table_a AS a +LEFT OUTER JOIN table_b AS b ON a.tenant_id = b.tenant_id +LEFT OUTER JOIN table_c AS c ON a.tenant_id = c.tenant_id +ORDER BY a.id, b.id, c.id; ROLLBACK;